|
--========================================================================================== |
|
SELECT product_id, p.name, (sum(s.units) * p.price) AS sales |
|
FROM products p LEFT JOIN sales s USING (product_id) |
|
GROUP BY product_id, p.name, p.price; |
|
--========================================================================================== |
|
SELECT product_id, p.name, (sum(s.units) * (p.price - p.cost)) AS profit |
|
FROM products p LEFT JOIN sales s USING (product_id) |
|
WHERE s.date > CURRENT_DATE - INTERVAL '4 weeks' |
|
GROUP BY product_id, p.name, p.price, p.cost |
|
HAVING sum(p.price * s.units) > 5000; |
|
--========================================================================================== |
|
SELECT brand, size, sum(sales) FROM items_sold GROUP BY GROUPING SETS ((brand), (size), ()); |
|
--========================================================================================== |
|
SELECT uid |
|
FROM subscribes |
|
GROUP BY uid |
|
HAVING COUNT(*) > 2 |
|
AND max( CASE "subscription_type" WHEN 'type1' THEN 1 ELSE 0 END ) = 0 |
|
--========================================================================================== |
|
SELECT Дата_продажи |
|
FROM Продажи |
|
GROUP BY Дата_продажи |
|
HAVING COUNT(DISTINCT Менеджер_ID) = (SELECT COUNT(DISTINCT Менеджер_ID) FROM Продажи); |
|
--========================================================================================== |
|
SELECT Email FROM Person GROUP BY Email HAVING COUNT(Email) > 1 |
|
--========================================================================================== |
|
SELECT DISTINCT a.Email FROM Person a JOIN Person b ON a.Email = b. Email WHERE a.Id != b.Id |
|
--========================================================================================== |
|
SELECT DISTINCT p1.Email FROM Person p1 WHERE EXISTS( SELECT * FROM Person p2 WHERE p2.Email = p1.Email AND p2.Id != p1.Id ) |
|
--========================================================================================== |
|
SELECT table_name FROM information_schema.tables WHERE table_type = 'base table' AND table_schema='test'; |
|
--========================================================================================== |
|
SELECT |
|
e.first_name, d.department_name, e.salary |
|
FROM |
|
employees e |
|
JOIN |
|
departments d |
|
ON |
|
(e.department_id = d.department_id) |
|
WHERE |
|
e.first_name |
|
IN |
|
(SELECT TOP 2 |
|
first_name |
|
FROM |
|
employees |
|
WHERE |
|
department_id = d.department_id); |
|
--========================================================================================== |
|
-- postgresql sample sql |
|
|
|
create view v2 as |
|
SELECT distributors.name |
|
FROM distributors |
|
WHERE distributors.name LIKE 'W%' |
|
UNION |
|
SELECT actors.name |
|
FROM actors |
|
WHERE actors.name LIKE 'W%'; |
|
|
|
|
|
WITH t AS ( |
|
SELECT random() as x FROM generate_series(1, 3) |
|
) |
|
SELECT * FROM t |
|
UNION ALL |
|
SELECT * FROM t |
|
; |
|
|
|
create view v3 as |
|
WITH RECURSIVE employee_recursive(distance, employee_name, manager_name) AS ( |
|
SELECT 1, employee_name, manager_name |
|
FROM employee |
|
WHERE manager_name = 'Mary' |
|
UNION ALL |
|
SELECT er.distance + 1, e.employee_name, e.manager_name |
|
FROM employee_recursive er, employee e |
|
WHERE er.employee_name = e.manager_name |
|
) |
|
SELECT distance, employee_name FROM employee_recursive; |
|
|
|
WITH upd AS ( |
|
UPDATE employees SET sales_count = sales_count + 1 WHERE id = |
|
(SELECT sales_person FROM accounts WHERE name = 'Acme Corporation') |
|
RETURNING * |
|
) |
|
INSERT INTO employees_log SELECT *, current_timestamp FROM upd; |
|
|
|
|
|
/* not implemented |
|
CREATE RECURSIVE VIEW nums_1_100 (n) AS |
|
VALUES (1) |
|
UNION ALL |
|
SELECT n+1 FROM nums_1_100 WHERE n < 100; |
|
*/ |
|
--========================================================================================== |
|
insert into emp (id,first_name,last_name,city,postal_code,ph) |
|
select a.id,a.first_name,a.last_name,a.city,a.postal_code,b.ph |
|
from emp_addr a |
|
inner join emp_ph b on a.id = b.id; |
|
--========================================================================================== |
|
Select distinct W.WORKER_ID, W.FIRST_NAME, W.Salary |
|
from Worker W, Worker W1 |
|
where W.Salary = W1.Salary |
|
and W.WORKER_ID != W1.WORKER_ID; |
|
--========================================================================================== |
|
Select max(Salary) from Worker |
|
where Salary not in (Select max(Salary) from Worker); |
|
--========================================================================================== |
|
SELECT * INTO newTable |
|
FROM EmployeeDetails |
|
WHERE 1 = 0; |
|
--========================================================================================== |
|
SELECT * FROM table1 |
|
SELECT COUNT(*) FROM table1 |
|
SELECT rows FROM sysindexes WHERE id = OBJECT_ID(table1) AND indid < 2 |
|
--========================================================================================== |
|
UPDATE table SET emp_name = CASE WHEN emp_name = 'chuck' THEN 'charles' ELSE emp_name END WHERE 'chuck' IN (emp_name); |
|
--========================================================================================== |
|
create function reverse(IN instring VARCHAR(20)) |
|
RETURNS VARCHAR(20) |
|
LANGUAGE SQL |
|
DETERMINISTIC |
|
BEGIN |
|
if char_length(instring) in (0, 1) |
|
then return (instring) |
|
else return (reverse(substring(instring from (char_length(instring) / 2 + 1)) |
|
|| reverse(substring(instring from 1 for char_length(instring)/ 2)))); |
|
end if; |
|
end; |
|
--========================================================================================== |
|
select * from department d, employee e; |
|
select * from department d, employee e where 1=1; |
|
select * from department d join employee e on 1=1; |
|
--========================================================================================== |
|
create table Personnel( |
|
emp_nbr integer default 0 not null primary key, |
|
emp_name varchar(10) default '{{vacant}}' not null, |
|
emp_address varchar(35) not null, |
|
birtdh_date date not null |
|
); |
|
|
|
create table OrgChart( |
|
job_title varchar(30) not null primary key, |
|
emp_nbr integer default 0 not null references Personnel(emp_nbr) on delete set default on update cascade, |
|
boss_emp_nbr integer references Personnel(emp_nbr), |
|
salary_amt decimal(12,4) not null check(salary_amt >= 0.00) |
|
); |
|
|
|
create function treetest() returns char(6) |
|
language sql |
|
deterministic |
|
begin atomic |
|
insert into temptree select emp_nbr, boss_emp_nbr from OrgChart; |
|
while(select count(*) from temptree) - 1 = (select count(boss_emp_nbr) from TempTree) |
|
do delete from temptree |
|
where temptree.emp_name not in (select t2.boss_emp_nbr from temptree as t2 where t2.boss_emp_nbr is not null); |
|
if not exists (select * from temptree) |
|
then return ('tree'); |
|
else return ('cycles'); |
|
end if; |
|
end while; |
|
end; |
|
|
|
create assertion validtree |
|
check ( |
|
(select count(*) from Tree) = (select count(*) from (select parent_node from Tree) union (select child_node from Tree)) |
|
); |
|
|
|
create view v1(emp_nbr, emp_name, boss_emp_nbr, boss_emp_name) |
|
as |
|
select e1.emp_nbr, e1.emp_name, e1.boss_emp_nbr, b1.emp_name from Personnel E1, Personnel B1, OrgChart P1 |
|
where b1.emp_nbr = p1.boss_emp_nbr and e1.emp_nbr = p1.emp_nbr; |
|
|
|
select distinct boss_emp_nbr from OrgChart where boss_emp_nbr not in (select emp_nbr from OrgChart); |
|
--========================================================================================== |
|
create or replace function should_increase_salary( |
|
cur_salary numeric, |
|
max_salary numeric DEFAULT 80, |
|
min_salary numeric DEFAULT 30, |
|
increase_rate numeric DEFAULT 0.2 |
|
) returns bool AS $$ |
|
declare |
|
new_salary numeric; |
|
begin |
|
if cur_salary >= max_salary or cur_salary >= min_salary then |
|
return false; |
|
end if; |
|
|
|
if cur_salary < min_salary then |
|
new_salary = cur_salary + (cur_salary * increase_rate); |
|
end if; |
|
|
|
if new_salary > max_salary then |
|
return false; |
|
else |
|
return true; |
|
end if; |
|
end; |
|
$$ language plpgsql; |
|
|
|
create or replace function get_season(month_number int) returns text AS $$ |
|
declare |
|
season text; |
|
begin |
|
if month_number NOT BETWEEN 1 and 12 THEN |
|
RAISE EXCEPTION 'Invalid month. You passed:(%)', month_number USING HINT='Allowed from 1 up to 12', ERRCODE=12882; |
|
end if; |
|
|
|
if month_number BETWEEN 3 and 5 then |
|
season = 'Spring'; |
|
elsif month_number BETWEEN 6 and 8 then |
|
season = 'Summer'; |
|
elsif month_number BETWEEN 9 and 11 then |
|
season = 'Autumn'; |
|
else |
|
season = 'Winter'; |
|
end if; |
|
|
|
return season; |
|
|
|
end; |
|
$$ language plpgsql; |
|
|
|
|
|
create or replace function get_season_caller1(month_number int) returns text AS $$ |
|
declare |
|
err_ctx text; |
|
err_msg text; |
|
err_details text; |
|
err_code text; |
|
BEGIN |
|
return get_season(15); |
|
EXCEPTION |
|
WHEN SQLSTATE '12882' then |
|
GET STACKED DIAGNOSTICS err_ctx = PG_EXCEPTION_CONTEXT, |
|
err_msg = MESSAGE_TEXT, |
|
err_details = PG_EXCEPTION_DETAIL, |
|
err_code = RETURNED_SQLSTATE; |
|
RAISE INFO 'My custom handler:'; |
|
RAISE INFO 'Error msg:%', err_msg; |
|
RAISE INFO 'Error details:%', err_details; |
|
RAISE INFO 'Error code:%', err_code; |
|
RAISE INFO 'Error context:%', err_ctx; |
|
RETURN NULL; |
|
END; |
|
$$ language plpgsql; |
|
|
|
create or replace function get_season_caller2(month_number int) returns text AS $$ |
|
declare |
|
err_ctx text; |
|
text_var1 text; |
|
text_var2 text; |
|
text_var3 text; |
|
BEGIN |
|
return get_season(15); |
|
EXCEPTION |
|
--when others then |
|
WHEN SQLSTATE '12882' then |
|
--won't catch by another code |
|
RAISE INFO 'My custom handler:'; |
|
RAISE INFO 'Error Name:%',SQLERRM; |
|
RAISE INFO 'Error State:%', SQLSTATE; |
|
RETURN NULL; |
|
END; |
|
$$ language plpgsql; |
|
--========================================================================================== |
|
select * |
|
into tmp_customers |
|
from department; |
|
|
|
select * |
|
from tmp_customers |
|
|
|
create or replace function fix_customer_region() returns void AS $$ |
|
update tmp_customers |
|
set region = 'unknown' |
|
where region is null |
|
$$ language sql |
|
|
|
--show functions section in pgAdmin |
|
--then demonstrate |
|
select fix_customer_region() |
|
|
|
--hw |
|
|
|
select * |
|
into tmp_order |
|
from employee; |
|
|
|
create or replace function fix_orders_ship_region() returns void AS $$ |
|
update tmp_order |
|
set ship_region = 'unknown' |
|
where ship_region is null |
|
$$ language sql |
|
|
|
select fix_orders_ship_region() |
|
--========================================================================================== |
|
create or replace function get_total_number_of_goods() returns bigint AS $$ |
|
select sum(units_in_stock) |
|
from products |
|
$$ language sql; |
|
|
|
create or replace function get_total_number_of_goods() returns real AS $$ |
|
select avg(unit_price) |
|
from products |
|
$$ language sql; |
|
|
|
|
|
|
|
select get_total_number_of_goods() as total_goods --as в самой функции будет проигнорирован |
|
|
|
--hw |
|
create or replace function get_max_price_from_discontinued() returns real AS $$ |
|
select max(unit_price) |
|
from products |
|
where discontinued = 1 |
|
$$ language sql; |
|
|
|
select get_max_price_from_discontinued() |
|
|
|
--Unless the function is declared to return void, |
|
--the last statement must be a SELECT, or an INSERT, UPDATE, or DELETE that has a RETURNING clause. |
|
|
|
--*DO*-- |
|
--DO executes an anonymous code block, or in other words a transient anonymous function in a procedural language. |
|
--The code block is treated as though it were the body of a function with no parameters, returning void. It is parsed and executed a single time. |
|
DO $$ |
|
BEGIN |
|
select sum(units_in_stock) |
|
from products |
|
END$$; |
|
--========================================================================================== |
|
drop function if exists get_price_boundaries; |
|
create or replace function get_price_boundaries(out max_price real, out min_price real) AS $$ |
|
SELECT MAX(unit_price), MIN(unit_price) |
|
FROM products |
|
$$ language sql; |
|
|
|
select get_price_boundaries() |
|
|
|
-- |
|
|
|
drop function if exists get_price_boundaries_by_discontinuity; |
|
create or replace function get_price_boundaries_by_discontinuity(in is_discontinued int, out max_price real, out min_price real) AS $$ |
|
SELECT MAX(unit_price), MIN(unit_price) |
|
FROM products |
|
where discontinued = is_discontinued |
|
$$ language sql; |
|
|
|
select get_price_boundaries_by_discontinuity(1) |
|
|
|
--HW |
|
drop function if exists get_freight_boundaries_by_shipped_dates; |
|
create or replace function get_freight_boundaries_by_shipped_dates( |
|
start_date date, end_date date, out max_price real, out min_price real |
|
) AS $$ |
|
|
|
SELECT MAX(freight), MIN(freight) |
|
FROM orders |
|
where shipped_date BETWEEN start_date and end_date |
|
|
|
$$ language sql; |
|
|
|
select get_freight_boundaries_by_shipped_dates('1997-06-01', '1997-06-12') |
|
|
|
select * |
|
from orders |
|
--========================================================================================== |
|
drop function if exists get_price_boundaries_by_discontinuity; |
|
create or replace function get_price_boundaries_by_discontinuity |
|
(in is_discontinued int DEFAULT 1, out max_price real, out min_price real) AS $$ |
|
SELECT MAX(unit_price), MIN(unit_price) |
|
FROM products |
|
where discontinued = is_discontinued |
|
$$ language sql; |
|
|
|
select get_price_boundaries_by_discontinuity(1); |
|
select get_price_boundaries_by_discontinuity(); --with default |
|
|
|
--hw |
|
drop function if exists get_freight_boundaries_by_shipped_dates; |
|
create or replace function get_freight_boundaries_by_shipped_dates( |
|
start_date date DEFAULT '1997-06-01', end_date date DEFAULT '1997-06-12', out max_price real, out min_price real |
|
) AS $$ |
|
|
|
SELECT MAX(freight), MIN(freight) |
|
FROM orders |
|
where shipped_date BETWEEN start_date and end_date |
|
|
|
$$ language sql; |
|
|
|
select get_freight_boundaries_by_shipped_dates('1997-06-01', '1997-06-12'); |
|
select get_freight_boundaries_by_shipped_dates(); |
|
--========================================================================================== |
|
--*How to return a set of primitive type values*-- |
|
drop function if exists get_average_prices_by_product_categories; |
|
create or replace function get_average_prices_by_product_categories() |
|
returns setof double precision as $$ |
|
|
|
select AVG(unit_price) |
|
from products |
|
group by category_id |
|
|
|
$$ language sql; |
|
|
|
select * from get_average_prices_by_product_categories() |
|
--to name the resulting column use 'as' |
|
select * from get_average_prices_by_product_categories() as average_prices |
|
|
|
--*How to return a set of columns*-- |
|
--*With OUT parameters*-- |
|
drop function if exists get_average_prices_by_product_categories; |
|
create or replace function get_average_prices_by_product_categories(out sum_price real, out avg_price float8) |
|
returns setof record as $$ |
|
|
|
select SUM(unit_price), AVG(unit_price) |
|
from products |
|
group by category_id; |
|
|
|
$$ language sql; |
|
|
|
select sum_price from get_average_prices_by_product_categories(); |
|
select sum_price, avg_price from get_average_prices_by_product_categories(); |
|
|
|
--won't work |
|
select sum_of, in_avg from get_average_prices_by_product_categories(); |
|
|
|
--will work |
|
select sum_price as sum_of, avg_price as in_avg |
|
from get_average_prices_by_product_categories(); |
|
|
|
--*How to return a set of columns*-- |
|
--*WithOUT OUT parameters*-- |
|
drop function if exists get_average_prices_by_product_categories; |
|
create or replace function get_average_prices_by_product_categories() |
|
returns setof record as $$ |
|
|
|
select SUM(unit_price), AVG(unit_price) |
|
from products |
|
group by category_id; |
|
|
|
$$ language sql; |
|
|
|
--won't work in all 4 syntax options |
|
select sum_price from get_average_prices_by_product_categories(); |
|
select sum_price, avg_price from get_average_prices_by_product_categories(); |
|
select sum_of, in_avg from get_average_prices_by_product_categories(); |
|
select * from get_average_prices_by_product_categories(); |
|
|
|
--works only this |
|
select * from get_average_prices_by_product_categories() as (sum_price real, avg_price float8); |
|
|
|
--returns table |
|
drop function if exists get_customers_by_country; |
|
create or replace function get_customers_by_country(customer_country varchar) |
|
returns table(char_code char, company_name varchar) as $$ |
|
|
|
select customer_id, company_name |
|
from customers |
|
where country = customer_country |
|
|
|
$$ language sql; |
|
|
|
--правила селекта все те же что и при returns setof |
|
select * from get_customers_by_country('USA'); |
|
select company_name from get_customers_by_country('USA'); |
|
select char_code, company_name from get_customers_by_country('USA'); |
|
|
|
--setof table |
|
drop function if exists get_customers_by_country; |
|
create or replace function get_customers_by_country(customer_country varchar) |
|
returns setof customers as $$ |
|
|
|
-- won't work: select company_name, contact_name |
|
select * |
|
from customers |
|
where country = customer_country |
|
|
|
$$ language sql; |
|
|
|
select * from get_customers_by_country('USA'); |
|
-- получим просто простыню текста: select get_customers_by_country('USA'); |
|
|
|
select contact_name, city |
|
from get_customers_by_country('USA'); |
|
|
|
|
|
--hw |
|
drop function if exists sold_more_than; |
|
create or replace function sold_more_than(min_sold_boundary int) |
|
returns setof products as $$ |
|
|
|
select * from products |
|
where product_id IN ( |
|
select product_id from |
|
(select sum(quantity), product_id |
|
from order_details |
|
group by product_id |
|
having sum(quantity) >min_sold_boundary |
|
) as filtered_out |
|
) |
|
|
|
$$ language sql; |
|
|
|
select sold_more_than(100) |
|
--========================================================================================== |
|
--*RETURN in plpgsql*-- |
|
CREATE OR REPLACE FUNCTION get_total_number_of_goods() RETURNS bigint AS $$ |
|
BEGIN |
|
RETURN sum(units_in_stock) |
|
FROM products; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
SELECT get_total_number_of_goods(); |
|
|
|
CREATE OR REPLACE FUNCTION get_max_price_from_discontinued() RETURNS real AS $$ |
|
BEGIN |
|
RETURN max(unit_price) |
|
FROM products |
|
WHERE discontinued = 1; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
SELECT get_max_price_from_discontinued(); |
|
|
|
CREATE OR REPLACE FUNCTION get_price_boundaries(OUT max_price real, OUT min_price real) AS $$ |
|
BEGIN |
|
--max_price := MAX(unit_price) FROM products; |
|
--min_price := MIN(unit_price) FROM products; |
|
SELECT MAX(unit_price), MIN(unit_price) |
|
INTO max_price, min_price |
|
FROM products; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
SELECT * FROM get_price_boundaries(); |
|
|
|
CREATE OR REPLACE FUNCTION get_sum(x int, y int, out result int) AS $$ |
|
BEGIN |
|
result = x + y; |
|
RETURN; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
SELECT * FROM get_sum(2, 3); |
|
|
|
DROP FUNCTION IF EXISTS get_customers_by_country; |
|
CREATE FUNCTION get_customers_by_country(customer_country varchar) RETURNS SETOF customers AS $$ |
|
BEGIN |
|
RETURN QUERY |
|
SELECT * |
|
FROM customers |
|
WHERE country = customer_country; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
SELECT * FROM get_customers_by_country('USA'); |
|
|
|
|
|
|
|
--* Declaring variables*--: |
|
drop function if exists get_square; |
|
create or replace function get_square(ab real, bc real, ac real) returns real AS $$ |
|
declare |
|
perimeter real; |
|
begin |
|
perimeter:=(ab+bc+ac)/2; |
|
return sqrt(perimeter * (perimeter - ab) * (perimeter - bc) * (perimeter - ac)); |
|
end; |
|
$$ language plpgsql; |
|
|
|
select get_square(6, 6, 6) |
|
|
|
--*Final example here*-- |
|
CREATE OR REPLACE FUNCTION middle_priced() |
|
RETURNS SETOF products AS $$ |
|
|
|
DECLARE |
|
average_price real; |
|
bottom_price real; |
|
top_price real; |
|
BEGIN |
|
SELECT AVG(unit_price) INTO average_price |
|
FROM products; |
|
|
|
bottom_price := average_price * .75; |
|
top_price := average_price * 1.25; |
|
|
|
RETURN QUERY SELECT * FROM products |
|
WHERE unit_price between bottom_price AND top_price; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
--========================================================================================== |
|
--*IF-THEN-ELSE*-- |
|
drop function if exists convert_temp_to; |
|
create or replace function convert_temp_to(temperature real, to_celsius bool DEFAULT true) returns real AS $$ |
|
declare |
|
result_temp real; |
|
begin |
|
if to_celsius then |
|
result_temp = (5.0/9.0)*(temperature-32); |
|
else |
|
result_temp:=(9*temperature+(32*5))/5.0; |
|
end if; |
|
|
|
return result_temp; |
|
end; |
|
$$ language plpgsql; |
|
|
|
select convert_temp_to(80); |
|
select convert_temp_to(26.7, false); |
|
|
|
--*IF-ELSIF-ELSE*-- |
|
|
|
drop function if exists get_season; |
|
create or replace function get_season(month_number int) returns text AS $$ |
|
declare |
|
season text; |
|
begin |
|
if month_number BETWEEN 3 and 5 then |
|
season = 'Spring'; |
|
elsif month_number BETWEEN 6 and 8 then |
|
season = 'Summer'; |
|
elsif month_number BETWEEN 9 and 11 then |
|
season = 'Autumn'; |
|
else |
|
season = 'Winter'; |
|
end if; |
|
|
|
return season; |
|
|
|
end; |
|
$$ language plpgsql; |
|
|
|
select get_season(12) |
|
--========================================================================================== |
|
CREATE OR REPLACE FUNCTION fibonacci (n INTEGER) |
|
RETURNS INTEGER AS $$ |
|
DECLARE |
|
counter INTEGER := 0 ; |
|
i INTEGER := 0 ; |
|
j INTEGER := 1 ; |
|
BEGIN |
|
IF (n < 1) THEN |
|
RETURN 0 ; |
|
END IF; |
|
|
|
WHILE counter <= n |
|
LOOP |
|
counter := counter + 1 ; |
|
SELECT j, i + j INTO i, j; |
|
END LOOP ; |
|
|
|
RETURN i ; |
|
END ; |
|
-- rewritten with explicit exit instead if WHILE-- |
|
CREATE OR REPLACE FUNCTION fibonacci (n INTEGER) |
|
RETURNS INTEGER AS $$ |
|
DECLARE |
|
counter INTEGER := 0 ; |
|
i INTEGER := 0 ; |
|
j INTEGER := 1 ; |
|
BEGIN |
|
|
|
IF (n < 1) THEN |
|
RETURN 0 ; |
|
END IF; |
|
|
|
LOOP |
|
EXIT WHEN counter = n ; |
|
counter := counter + 1 ; |
|
SELECT j, i + j INTO i, j ; |
|
END LOOP ; |
|
|
|
RETURN i ; |
|
END ; |
|
$$ LANGUAGE plpgsql; |
|
|
|
-- FOR IN -- |
|
DO $$ |
|
BEGIN |
|
FOR counter IN 1..5 LOOP |
|
RAISE NOTICE 'Counter: %', counter; |
|
END LOOP; |
|
END; $$ |
|
|
|
DO $$ |
|
BEGIN |
|
FOR counter IN REVERSE 5..1 LOOP |
|
RAISE NOTICE 'Counter: %', counter; |
|
END LOOP; |
|
END; $$ |
|
|
|
|
|
DO $$ |
|
BEGIN |
|
FOR counter IN 1..6 BY 2 LOOP |
|
RAISE NOTICE 'Counter: %', counter; |
|
END LOOP; |
|
END; $$ |
|
|
|
--*Continue and Iterate Over Array*-- |
|
CREATE OR REPLACE FUNCTION filter_even(variadic numbers int[]) returns setof int |
|
AS $$ |
|
BEGIN |
|
FOR counter IN 1..array_upper(numbers, 1) |
|
LOOP |
|
CONTINUE WHEN counter % 2 != 0; |
|
return next counter; |
|
END LOOP; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
select * from filter_even(1, 2, 3, 4, 5, 6) |
|
|
|
--*FOREACH*-- |
|
CREATE OR REPLACE FUNCTION filter_even(variadic numbers int[]) returns setof int |
|
AS $$ |
|
DECLARE |
|
counter int; |
|
BEGIN |
|
FOREACH counter IN ARRAY numbers |
|
LOOP |
|
CONTINUE WHEN counter % 2 != 0; |
|
return next counter; |
|
END LOOP; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
select * from filter_even(1, 2, 3, 4, 5, 6) |
|
|
|
-- Iterate Over a Query -- |
|
|
|
CREATE OR REPLACE FUNCTION iter_over_query(n INTEGER DEFAULT 5) |
|
RETURNS VOID AS $$ |
|
DECLARE |
|
rec RECORD; |
|
BEGIN |
|
FOR rec IN SELECT * |
|
FROM products |
|
ORDER BY unit_price |
|
LIMIT n |
|
LOOP |
|
RAISE NOTICE '%', rec.product_name; --don't forget to look at messages |
|
END LOOP; |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
select * from iter_over_query() |
|
|
|
--*RETURN NEXT*-- |
|
-- Иногда нам необходима построчная обработка данных и уже затем построчный их возврат из функции |
|
-- в таком случае надо использовать выражение RETURN NEXT для возврата каждой строки. |
|
-- Это выражение можно вызывать несколько раз и результатом каждого вызова будет новая строка в выходном наборе данных. |
|
-- Вот простейший пример: |
|
CREATE OR REPLACE FUNCTION return_setof_int() RETURNS SETOF int AS |
|
$$ |
|
BEGIN |
|
RETURN NEXT 1; |
|
RETURN NEXT 2; |
|
RETURN NEXT 3; |
|
RETURN; -- Необязательный |
|
END |
|
$$ LANGUAGE plpgsql; |
|
|
|
--RETURN NEXT: |
|
CREATE OR REPLACE FUNCTION test0() |
|
RETURNS TABLE(y integer, result text) AS $$ |
|
BEGIN |
|
FOR y, result IN |
|
SELECT s.y, 'hi' result FROM generate_series(1,10,1) AS s(y) |
|
LOOP |
|
RETURN NEXT y; |
|
END LOOP; |
|
END |
|
$$ LANGUAGE plpgsql; |
|
|
|
SELECT * FROM test0(); |
|
|
|
--а вот пример посложнее-- |
|
CREATE OR REPLACE FUNCTION after_christmas_sale() RETURNS SETOF products AS $$ |
|
DECLARE |
|
product record; |
|
BEGIN |
|
FOR product IN |
|
SELECT * FROM products |
|
LOOP |
|
IF product.category_id IN (1,4,8) THEN |
|
product.unit_price = product.unit_price * .80; |
|
ELSIF product.category_id IN (2,3,7) THEN |
|
product.unit_price = product.unit_price * .75; |
|
ELSE |
|
product.unit_price = product.unit_price * 1.10; |
|
END IF; |
|
RETURN NEXT product; |
|
END LOOP; |
|
|
|
RETURN; |
|
|
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
SELECT * FROM after_christmas_sale(); |
|
--========================================================================================== |
|
CREATE OR REPLACE FUNCTION random_between(low INT ,high INT) |
|
RETURNS INT AS |
|
$$ |
|
BEGIN |
|
RETURN floor(random()* (high-low + 1) + low); |
|
END; |
|
$$ language 'plpgsql' STRICT; |
|
--========================================================================================== |
|
--string functions-- |
|
select chr(72); |
|
|
|
select concat('Abra', '-abra-', 'cadabra'); |
|
|
|
select upper('abcd'); -- удобно для сравнения |
|
select lower('ABCD'); |
|
|
|
select initcap('hello, John'); |
|
|
|
--substring-related funcs |
|
select position('lo' in 'hello'); --starting at 4 |
|
select overlay('h___o' placing 'ell' from 2 for 3); -- where from and how many chars |
|
|
|
select substring('abra_cadabra_abra' from 6 for 7) -- by index & number of chars |
|
--select using regex (by posix and sql) |
|
|
|
select trim(both ' ' from ' Hello '); |
|
select trim(leading ' ' from ' Hello '); |
|
select trim(trailing ' ' from ' Hello '); |
|
|
|
--select convert('text_in_ascii', 'ascii', 'UTF8') |
|
|
|
--replace |
|
|
|
--numerical functions-- |
|
select abs(-1), abs(1); |
|
|
|
--what about rounding mode? |
|
select round(3.4),round(3.6),round(3.6); |
|
select ceil(3.4),ceil(3.5),ceil(3.6),ceil(4); |
|
select floor(3.4),floor(3.5),floor(3.6), floor(4); |
|
|
|
select sign(-1), sign(1); |
|
|
|
select mod(5, 2), mod(4, 2); |
|
select mod(5,2)=0; --if it is even? |
|
|
|
select sqrt(16), sqrt(4.5); |
|
select format(sqrt(4.5), 2); |
|
select power(2, 5) --or pow in short |
|
|
|
select greatest(1,2,3,4,5); |
|
|
|
--DATES & TIMES-- |
|
select current_date; |
|
|
|
select |
|
extract(day from date '2020-02-20') as day, |
|
extract(month from date '2020-01-15') as month, |
|
extract(year from date '2020-01-15') as year |
|
|
|
select date_trunc('month', date'2020-01-15') -- cut off days |
|
select date_trunc('year', date'2020-01-15') -- cut off months & days |
|
|
|
select current_date + integer '3'; |
|
select current_date + interval '2 hours 30 minutes'; |
|
select current_date + interval '1 day'; |
|
|
|
select localtimestamp + interval '2 hours 30 minutes'; |
|
select localtimestamp + time '02:30'; |
|
|
|
--conversion-- |
|
|
|
--todo: casting example |
|
|
|
select convert(int, 2.5); |
|
--========================================================================================== |
|
SELECT product_name, unit_price, |
|
CASE WHEN units_in_stock >= 100 THEN 'lots of' |
|
WHEN units_in_stock >= 50 AND units_in_stock < 100 THEN 'average' |
|
WHEN units_in_stock < 50 THEN 'low number' |
|
ELSE 'unknown' |
|
END AS amount |
|
FROM products; |
|
|
|
SELECT order_id, order_date, |
|
CASE WHEN date_part('month', order_date) BETWEEN 3 and 5 THEN 'spring' |
|
WHEN date_part('month', order_date) BETWEEN 6 and 8 THEN 'summer' |
|
WHEN date_part('month', order_date) BETWEEN 9 and 11 THEN 'autumn' |
|
ELSE 'winter' |
|
END AS bla |
|
FROM orders; |
|
--========================================================================================== |
|
SELECT * |
|
FROM orders |
|
LIMIT 10; |
|
|
|
SELECT order_id, order_date, COALESCE(ship_region, 'unknown') AS ship_region |
|
FROM orders |
|
LIMIT 10; |
|
|
|
SELECT * |
|
FROM employees; |
|
|
|
SELECT last_name, first_name, COALESCE(region, 'N/A') as region |
|
FROM employees; |
|
|
|
SELECT contact_name, COALESCE(NULLIF(city, ''), 'Unknown') as city |
|
FROM customers; |
|
|
|
CREATE TABLE budgets |
|
( |
|
dept serial, |
|
current_year decimal NULL, |
|
previous_year decimal NULL |
|
); |
|
|
|
INSERT INTO budgets(current_year, previous_year) VALUES(100000, 150000); |
|
INSERT INTO budgets(current_year, previous_year) VALUES(NULL, 300000); |
|
INSERT INTO budgets(current_year, previous_year) VALUES(0, 100000); |
|
INSERT INTO budgets(current_year, previous_year) VALUES(NULL, 150000); |
|
INSERT INTO budgets(current_year, previous_year) VALUES(300000, 250000); |
|
INSERT INTO budgets(current_year, previous_year) VALUES(170000, 170000); |
|
INSERT INTO budgets(current_year, previous_year) VALUES(150000, NULL); |
|
|
|
SELECT dept, |
|
COALESCE(TO_CHAR(NULLIF(current_year, previous_year), 'FM99999999'), 'Same as last year') AS budget |
|
FROM budgets |
|
WHERE current_year IS NOT NULL; |
|
--========================================================================================== |
|
SELECT contact_name, city, country |
|
FROM customers |
|
ORDER BY contact_name, |
|
( |
|
CASE WHEN city IS NULL THEN country |
|
ELSE city |
|
END |
|
); |
|
|
|
INSERT INTO customers(customer_id, contact_name, city, country, company_name) |
|
VALUES |
|
('AAAAAB', 'John Mann', 'abc', 'USA', 'fake_company'), |
|
('BBBBBV', 'John Mann', 'acd', 'Austria', 'fake_company'); |
|
|
|
SELECT product_name, unit_price, |
|
CASE WHEN unit_price >= 100 THEN 'too expensive' |
|
WHEN unit_price >= 50 AND unit_price < 100 THEN 'average' |
|
ELSE 'low price' |
|
END AS price |
|
FROM products |
|
ORDER BY unit_price DESC; |
|
|
|
SELECT DISTINCT contact_name, COALESCE(order_id::text, 'no orders') |
|
FROM customers |
|
LEFT JOIN orders USING(customer_id) |
|
WHERE order_id IS NULL; |
|
|
|
SELECT CONCAT(last_name, ' ', first_name), COALESCE(NULLIF(title, 'Sales Representative'), 'Sales Stuff') AS title |
|
FROM employees; |
|
--========================================================================================== |
|
CREATE OR REPLACE VIEW heavy_orders AS |
|
SELECT * |
|
FROM orders |
|
WHERE freight > 100; |
|
|
|
SELECT * |
|
FROM heavy_orders |
|
ORDER BY freight; |
|
|
|
INSERT INTO heavy_orders |
|
VALUES(11900, 'FOLIG', 1, '2000-01-01', '2000-01-05', '2000-01-04', 1, 80, 'Folies gourmandes', '184, chaussee de Tournai', |
|
'Lille', NULL, 59000, 'FRANCE'); |
|
|
|
SELECT * |
|
FROM heavy_orders |
|
WHERE order_id = 11900; |
|
|
|
CREATE OR REPLACE VIEW heavy_orders AS |
|
SELECT * |
|
FROM orders |
|
WHERE freight > 100 |
|
WITH LOCAL CHECK OPTION; |
|
|
|
CREATE OR REPLACE VIEW heavy_orders AS |
|
SELECT * |
|
FROM orders |
|
WHERE freight > 100 |
|
WITH CASCADE CHECK OPTION; |
|
--========================================================================================== |
|
CREATE VIEW orders_customers_employees AS |
|
SELECT order_date, required_date, shipped_date, ship_postal_code, |
|
company_name, contact_name, phone, |
|
last_name, first_name, title |
|
FROM orders |
|
JOIN customers USING (customer_id) |
|
JOIN employees USING (employee_id); |
|
|
|
SELECT * |
|
FROM orders_customers_employees |
|
WHERE order_date > '1997-01-01'; |
|
|
|
-- |
|
|
|
CREATE OR REPLACE VIEW orders_customers_employees AS |
|
SELECT order_date, required_date, shipped_date, ship_postal_code, ship_country, --add ship_country |
|
company_name, contact_name, phone, postal_code, --add postal_code |
|
last_name, first_name, title, reports_to --add reports_to |
|
FROM orders |
|
JOIN customers USING (customer_id) |
|
JOIN employees USING (employee_id); |
|
|
|
SELECT * |
|
FROM orders_customers_employees |
|
ORDER BY ship_country; |
|
|
|
-- |
|
ALTER VIEW products_suppliers_categories RENAME TO products_detailed; |
|
|
|
-- |
|
DROP VIEW IF EXISTS orders_customers_employees; |
|
|
|
select * from products; |
|
|
|
drop view active_products; |
|
create or replace view active_products |
|
as |
|
select product_id, product_name, supplier_id, category_id, quantity_per_unit, unit_price, |
|
units_in_stock, units_on_order, reorder_level, discontinued |
|
FROM products |
|
where discontinued <> 1 |
|
with local check option; |
|
|
|
insert into active_products |
|
values(78, 'abc', 1, 1, 'abc', 1, 1, 1, 1, 1); |
|
|
|
-- |
|
SELECT product_name, unit_price, |
|
CASE WHEN unit_price>95 THEN 'expensive' |
|
WHEN unit_price>= 50 and unit_price < 95 THEN 'middle range' |
|
WHEN unit_price < 50 THEN 'cheap' |
|
END AS expensiveness |
|
FROM products |
|
ORDER BY unit_price DESC; |
|
|
|
-- |
|
select company_name, coalesce(region, 'unknown region') |
|
from suppliers; |
|
--========================================================================================== |
|
select constraint_name |
|
from information_schema.key_column_usage |
|
where table_name = 'chair' |
|
and table_schema = 'public' |
|
and column_name = 'cathedra_id'; |
|
--========================================================================================== |
|
CREATE TABLE customer |
|
( |
|
customer_id serial, |
|
full_name text, |
|
status char DEFAULT 'r', |
|
|
|
CONSTRAINT PK_customer_id PRIMARY KEY(customer_id), |
|
CONSTRAINT CHK_customer_status CHECK (status = 'r' or status = 'p') |
|
); |
|
|
|
INSERT INTO customer |
|
VALUES |
|
(1, 'name'); |
|
|
|
SELECT * |
|
FROM customer; |
|
|
|
INSERT INTO customer |
|
VALUES |
|
(1, 'name', 'd'); |
|
|
|
ALTER TABLE customer |
|
ALTER COLUMN status DROP DEFAULT; |
|
|
|
ALTER TABLE customer |
|
ALTER COLUMN status SET DEFAULT 'r'; |
|
--========================================================================================== |
|
CREATE SEQUENCE seq; |
|
|
|
SELECT nextval('seq'); |
|
SELECT currval('seq'); |
|
SELECT lastval(); |
|
|
|
-- |
|
SELECT setval('seq', 10); |
|
SELECT currval('seq'); |
|
SELECT nextval('seq'); |
|
|
|
SELECT setval('seq', 16, false); |
|
SELECT currval('seq'); |
|
SELECT nextval('seq'); |
|
|
|
-- |
|
CREATE SEQUENCE IF NOT EXISTS seq2 INCREMENT 16; |
|
SELECT nextval('seq2'); |
|
|
|
-- |
|
CREATE SEQUENCE IF NOT EXISTS seq3 |
|
INCREMENT 16 |
|
MINVALUE 0 |
|
MAXVALUE 128 |
|
START WITH 0 |
|
|
|
SELECT nextval('seq3'); |
|
|
|
ALTER SEQUENCE seq3 RENAME TO seq4 |
|
ALTER SEQUENCE seq4 RESTART WITH 16 |
|
SELECT nextval('seq4'); |
|
|
|
DROP SEQUENCE seq4; |
|
--========================================================================================== |
|
CREATE SEQUENCE IF NOT EXISTS book_book_id_seq |
|
START WITH 1 OWNED BY book.book_id; |
|
|
|
-- doesn't work |
|
INSERT INTO book (title, isbn, publisher_id) |
|
VALUES ('title', 'isbn', 1); |
|
|
|
--we need to set default |
|
ALTER TABLE book |
|
ALTER COLUMN book_id SET DEFAULT nextval('book_book_id_seq'); |
|
|
|
--now should work |
|
INSERT INTO book (title, isbn, publisher_id) |
|
VALUES ('title', 'isbn', 1); |
|
|
|
INSERT INTO book (title, isbn, publisher_id) |
|
VALUES ('title3', 'isbn3', 1) |
|
RETURNING book_id; |
|
--========================================================================================== |
|
INSERT INTO book(title, isbn, publisher_id) |
|
VALUES ('title', 'isbn', 3) |
|
RETURNING *; |
|
|
|
UPDATE author |
|
SET full_name = 'Walter', rating = 5 |
|
WHERE author_id = 1 |
|
RETURNING author_id; |
|
|
|
DELETE FROM author |
|
WHERE rating = 5 |
|
RETURNING *; |
|
--========================================================================================== |
|
SELECT * FROM author; |
|
|
|
UPDATE author |
|
SET full_name = 'Elias', rating = 5 |
|
WHERE author_id = 1; |
|
|
|
DELETE FROM author |
|
WHERE rating < 4.5; |
|
|
|
DELETE FROM author; |
|
|
|
TRUNCATE TABLE author; |
|
|
|
DROP TABLE book; |
|
|
|
CREATE TABLE book |
|
( |
|
book_id serial, |
|
title text NOT NULL, |
|
isbn varchar(32) NOT NULL, |
|
publisher_id int NOT NULL, |
|
|
|
CONSTRAINT PK_book_book_id PRIMARY KEY(book_id) |
|
); |
|
|
|
INSERT INTO book(title, isbn, publisher_id) |
|
VALUES ('title', 'isbn', 3) |
|
RETURNING *; |
|
|
|
UPDATE author |
|
SET full_name = 'Walter', rating = 5 |
|
WHERE author_id = 1 |
|
RETURNING author_id; |
|
|
|
DELETE FROM author |
|
WHERE rating = 5 |
|
RETURNING *; |
|
--========================================================================================== |
|
-- Subquery: что если мы хотим найти все компании поставщиков из тех стран, в которые делают заказы заказчики? |
|
SELECT company_name |
|
FROM suppliers |
|
WHERE country IN (SELECT country FROM customers) |
|
|
|
--equivalent query |
|
SELECT DISTINCT suppliers.company_name |
|
FROM suppliers |
|
JOIN customers USING(country) |
|
|
|
SELECT category_name, SUM(units_in_stock) |
|
FROM products |
|
INNER JOIN categories ON products.category_id = categories.category_id |
|
GROUP BY category_name |
|
ORDER BY SUM(units_in_stock) DESC |
|
LIMIT (SELECT MIN(product_id) + 4 FROM products) |
|
|
|
--среднее кол-во товаров в наличии |
|
SELECT AVG(units_in_stock) |
|
FROM products |
|
|
|
-- а если мы хотим вывести такие товары, количество которого в наличии больше чем в среднем |
|
SELECT product_name, units_in_stock |
|
FROM products |
|
WHERE units_in_stock > |
|
(SELECT AVG(units_in_stock) |
|
FROM products) |
|
ORDER BY units_in_stock |
|
--========================================================================================== |
|
--выбрать все уникальные компании заказчиков которые делали заказы на более чем 40 единиц товаров |
|
--с джойнами |
|
SELECT DISTINCT company_name |
|
FROM customers |
|
JOIN orders USING(customer_id) |
|
JOIN order_details USING(order_id) |
|
WHERE quantity > 40; |
|
|
|
--с подзапросом |
|
SELECT DISTINCT company_name --from course |
|
FROM customers |
|
WHERE customer_id = ANY(SELECT customer_id FROM orders |
|
JOIN order_details USING(order_id) |
|
WHERE quantity > 40); |
|
|
|
-- можно комбинировать джойны с подзапросами |
|
-- это у нас просто среднее количество единиц товара по всем заказам |
|
SELECT AVG(quantity) |
|
FROM order_details; |
|
|
|
-- давайте выберем такие продукты, количество которых больше среднего по заказам |
|
-- используя предыдущий запрос в качестве подзапроса можно написать следующий запрос: |
|
SELECT DISTINCT product_name, quantity |
|
FROM products |
|
JOIN order_details USING(product_id) |
|
WHERE quantity > |
|
(SELECT AVG(quantity) |
|
FROM order_details); |
|
|
|
|
|
-- найти все продукты количество которых больше среднего значения количества заказанных товаров из групп, полученных группированием по product_id |
|
SELECT AVG(quantity) |
|
FROM order_details |
|
GROUP BY product_id; |
|
|
|
SELECT DISTINCT product_name, quantity |
|
FROM products |
|
JOIN order_details USING(product_id) |
|
WHERE quantity > ALL |
|
(SELECT AVG(quantity) |
|
FROM order_details |
|
GROUP BY product_id) |
|
ORDER BY quantity; |
|
--========================================================================================== |
|
SELECT product_name, units_in_stock |
|
FROM products |
|
WHERE units_in_stock < ALL |
|
(SELECT AVG(quantity) |
|
FROM order_details |
|
GROUP BY product_id) |
|
ORDER BY units_in_stock DESC; |
|
|
|
SELECT AVG(quantity) |
|
FROM order_details |
|
GROUP BY product_id |
|
order by AVG(quantity) |
|
|
|
SELECT o.customer_id, SUM(o.freight) AS freight_sum |
|
FROM orders AS o |
|
INNER JOIN (SELECT customer_id, AVG(freight) AS freight_avg |
|
FROM orders |
|
GROUP BY customer_id) AS oa |
|
ON oa.customer_id = o.customer_id |
|
WHERE o.freight > oa.freight_avg |
|
AND o.shipped_date BETWEEN '1996-07-16' AND '1996-07-31' |
|
GROUP BY o.customer_id |
|
ORDER BY freight_sum; |
|
|
|
SELECT customer_id, ship_country, order_price |
|
FROM orders |
|
JOIN (SELECT order_id, |
|
SUM(unit_price * quantity - unit_price * quantity * discount) AS order_price |
|
FROM order_details |
|
GROUP BY order_id) od |
|
USING(order_id) |
|
WHERE ship_country IN ('Argentina' , 'Bolivia', 'Brazil', 'Chile', 'Colombia', 'Ecuador', 'Guyana', 'Paraguay', |
|
'Peru', 'Suriname', 'Uruguay', 'Venezuela') |
|
AND order_date >= '1997-09-01' |
|
ORDER BY order_price DESC |
|
LIMIT 3; |
|
|
|
SELECT product_name |
|
FROM products |
|
WHERE product_id = ANY (SELECT product_id FROM order_details WHERE quantity = 10); |
|
|
|
SELECT distinct product_name, quantity |
|
FROM products |
|
join order_details using(product_id) |
|
where order_details.quantity = 10 |
|
--========================================================================================== |
|
CREATE TABLE employee ( |
|
employee_id int PRIMARY KEY, |
|
first_name varchar(256) NOT NULL, |
|
last_name varchar(256) NOT NULL, |
|
manager_id int, |
|
FOREIGN KEY (manager_id) REFERENCES employee(employee_id); |
|
); |
|
|
|
INSERT INTO employee |
|
(employee_id, first_name, last_name, manager_id) |
|
VALUES |
|
(1, 'Windy', 'Hays', NULL), |
|
(2, 'Ava', 'Christensen', 1), |
|
(3, 'Hassan', 'Conner', 1), |
|
(4, 'Anna', 'Reeves', 2), |
|
(5, 'Sau', 'Norman', 2), |
|
(6, 'Kelsie', 'Hays', 3), |
|
(7, 'Tory', 'Goff', 3), |
|
(8, 'Salley', 'Lester', 3); |
|
|
|
SELECT e.first_name || ' ' || e.last_name AS employee, |
|
m.first_name || ' ' || m.last_name AS manager |
|
FROM employee e |
|
LEFT JOIN employee m ON m.employee_id = e.manager_id |
|
ORDER BY manager; |
|
--========================================================================================== |
|
SELECT COUNT(*) AS employees_count |
|
FROM employees; |
|
|
|
SELECT COUNT(DISTINCT country) AS country |
|
FROM employees; |
|
|
|
SELECT category_id, SUM(units_in_stock) AS units_in_stock |
|
FROM products |
|
GROUP BY category_id |
|
ORDER BY units_in_stock DESC |
|
LIMIT 5; |
|
|
|
SELECT category_id, SUM(unit_price * units_in_stock) AS total_price |
|
FROM products |
|
WHERE discontinued <> 1 |
|
GROUP BY category_id |
|
HAVING SUM(unit_price * units_in_stock) > 5000 |
|
ORDER BY total_price DESC; |
|
--========================================================================================== |
|
-- Найти заказчиков и обслуживающих их заказы сотрудкников |
|
-- таких, что и заказчики и сотрудники из города London, а доставка идёт компанией Speedy Express. |
|
-- Вывести компанию заказчика и ФИО сотрудника. |
|
SELECT c.company_name AS customer, |
|
CONCAT(e.first_name, ' ', e.last_name) AS employee |
|
FROM orders as o |
|
JOIN customers as c USING(customer_id) |
|
JOIN employees as e USING(employee_id) |
|
JOIN shippers as s ON o.ship_via = s.shipper_id |
|
WHERE c.city = 'London' |
|
AND e.city = 'London' |
|
AND s.company_name = 'Speedy Express'; |
|
|
|
-- Найти активные (см. поле discontinued) продукты из категории Beverages и Seafood, которых в продаже менее 20 единиц |
|
-- Вывести наименование продуктов, кол-во единиц в продаже, имя контакта поставщика и его телефонный номер. |
|
SELECT product_name, units_in_stock, contact_name, phone |
|
FROM products |
|
JOIN categories USING(category_id) |
|
JOIN suppliers USING(supplier_id) |
|
WHERE category_name IN ('Beverages', 'Seafood') |
|
AND discontinued = 0 |
|
AND units_in_stock < 20 |
|
ORDER BY units_in_stock; |
|
|
|
-- Найти заказчиков, не сделавших ни одного заказа |
|
-- Вывести имя заказчика и order_id |
|
SELECT distinct contact_name, order_id |
|
FROM customers |
|
LEFT JOIN orders USING(customer_id) |
|
WHERE order_id IS NULL |
|
ORDER BY contact_name; |
|
|
|
--Переписать предыдущий запрос, использовав симметричный вид джойна (подсказа: речь о LEFT и RIGHT) |
|
SELECT contact_name, order_id |
|
FROM orders |
|
RIGHT JOIN customers USING(customer_id) |
|
WHERE order_id IS NULL |
|
ORDER BY contact_name; |
|
--========================================================================================== |
|
SELECT ship_country, COUNT(*) |
|
FROM orders |
|
WHERE freight > 50 |
|
GROUP BY ship_country |
|
ORDER BY COUNT(*) DESC; |
|
|
|
SELECT category_id, SUM(UnitsInStock) |
|
FROM products |
|
GROUP BY category_id |
|
ORDER BY SUM(units_in_stock) DESC; |
|
LIMIT 5 |
|
|
|
SELECT category_id, SUM(unit_price * units_in_stock) |
|
FROM products |
|
WHERE discontinued <> 1 |
|
GROUP BY category_id |
|
HAVING SUM(unit_price * units_in_stock) > 5000 |
|
ORDER BY SUM(unit_price * units_in_stock) DESC; |
|
--========================================================================================== |
|
SELECT pg_terminate_backend(pg_stat_activity.pid) |
|
FROM pg_stat_activity |
|
WHERE pg_stat_activity.datname = 'testdb' |
|
AND pid <> pg_backend_pid() |
|
--========================================================================================== |
|
CREATE TABLE person |
|
( |
|
person_id int PRIMARY KEY, |
|
first_name varchar(64) NOT NULL, |
|
last_name varchar(64) NOT NULL |
|
); |
|
|
|
CREATE TABLE passport |
|
( |
|
passport_id int PRIMARY KEY, |
|
serial_number int NOT NULL, |
|
fk_passport_person int UNIQUE REFERENCES person(person_id) |
|
); |
|
|
|
INSERT INTO person VALUES (1, 'John', 'Snow'); |
|
INSERT INTO person VALUES (2, 'Ned', 'Stark'); |
|
INSERT INTO person VALUES (3, 'Rob', 'Baratheon'); |
|
|
|
ALTER TABLE passport |
|
ADD COLUMN registration text NOT NULL; |
|
|
|
INSERT INTO passport VALUES (1, 123456, 1, 'Winterfell'); |
|
INSERT INTO passport VALUES (2, 789012, 2, 'Winterfell'); |
|
INSERT INTO passport VALUES (3, 345678, 3, 'King''s Landing'); |
|
--========================================================================================== |
|
-- a) have a gander at monthly & weekly volume patterns of 2012 |
|
-- b) session volume & order volume |
|
|
|
-- a |
|
select |
|
year(website_sessions.created_at), |
|
month(website_sessions.created_at), |
|
count(distinct website_sessions.website_session_id) as sessions, |
|
count(distinct orders.order_id) as orders |
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2012-01-01' |
|
and website_sessions.created_at < '2013-01-02' |
|
group by |
|
1,2 |
|
order by 1,2; |
|
|
|
-- b |
|
select |
|
min(date(website_sessions.created_at)) as week_start_date, |
|
count(distinct website_sessions.website_session_id) as sessions, |
|
count(distinct orders.order_id) as orders |
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2012-01-01' |
|
and website_sessions.created_at < '2013-01-02' |
|
group by |
|
yearweek(website_sessions.created_at); |
|
--========================================================================================== |
|
-- average website session volume by hour of day & by day week |
|
|
|
select |
|
hr, |
|
avg(case when wkday = 1 then website_sessions else NULL end) as tue, |
|
avg(case when wkday = 2 then website_sessions else NULL end) as wed, |
|
avg(case when wkday = 3 then website_sessions else NULL end) as thu, |
|
avg(case when wkday = 4 then website_sessions else NULL end) as fri, |
|
avg(case when wkday = 5 then website_sessions else NULL end) as sat, |
|
avg(case when wkday = 6 then website_sessions else NULL end) as sun |
|
from |
|
( |
|
select |
|
date(created_at) as date, |
|
weekday(created_at) as wkday, |
|
hour(created_at) as hr, |
|
count(distinct website_session_id) as website_sessions |
|
from website_sessions |
|
where created_at > '2012-09-15' and created_at < '2012-11-15' |
|
group by 1,2,3 |
|
) as date_table |
|
group by 1 |
|
order by 1; |
|
--========================================================================================== |
|
-- count pageviews to identify 'bounces' and summarize by week |
|
select |
|
min(date(session_created)) as week_start_date, |
|
-- COUNT + CASE is a Pivot method |
|
count(distinct case when count_pageveiws = 1 then session else NULL end)*1.0/count(distinct session) as bounce_rate, |
|
count(distinct case when landing_page = '/home' then session else NULL end) as home_session, |
|
count(distinct case when landing_page = '/lander-1' then session else NULL end) as lander_sessions |
|
from landing_pages |
|
group by |
|
yearweek(session_created); |
|
--========================================================================================== |
|
-- pull data on how many of business website visitors come back for another session |
|
|
|
|
|
DROP TEMPORARY TABLE IF EXISTS repeat_sessions; |
|
|
|
create temporary table repeat_sessions |
|
select |
|
inner_table.user_id, |
|
inner_table.website_session_id as new_session_id, |
|
website_sessions.website_session_id as repeat_session_id |
|
from |
|
( |
|
select |
|
user_id, |
|
website_session_id |
|
from website_sessions |
|
where created_at < '2014-11-03' |
|
and created_at >= '2014-01-01' |
|
and is_repeat_session = 0 |
|
) as inner_table |
|
-- 'inner_table' will have only new queries |
|
left join website_sessions |
|
on website_sessions.user_id=inner_table.user_id |
|
and website_sessions.is_repeat_session = 1 -- can be, but redundant |
|
and website_sessions.website_session_id > inner_table.website_session_id |
|
-- above one specifies that repeat session should be further than initial one |
|
and website_sessions.created_at < '2014-11-03' |
|
and website_sessions.created_at >= '2014-01-01'; |
|
|
|
|
|
-- result |
|
select |
|
repeat_session_id, |
|
count(distinct user_id) as users |
|
from |
|
( |
|
select |
|
user_id, |
|
count(distinct new_session_id) as new_session_id, |
|
count(distinct repeat_session_id) as repeat_session_id |
|
from repeat_sessions |
|
group by 1 |
|
order by 3 desc |
|
) as users |
|
group by 1; |
|
--========================================================================================== |
|
-- compare new vs repeat sessions by channel |
|
|
|
-- output |
|
select |
|
case |
|
when utm_source is NULL and http_referer in ('https://www.gsearch.com', 'https://www.bsearch.com') |
|
then 'organic_search' |
|
when utm_source is NULL and http_referer is NULL then 'direct_type' |
|
when utm_campaign = 'nonbrand' then 'paid_nonbrand' |
|
when utm_campaign = 'brand' then 'paid_brand' |
|
when utm_source = 'socialbook' then 'paid_social' |
|
end as channel_group, |
|
-- utm_source, |
|
-- utm_campaign, |
|
-- http_referer, |
|
count(case when is_repeat_session = 0 then website_session_id else NULL end) as new_sessions, |
|
count(case when is_repeat_session = 1 then website_session_id else NULL end) as repeat_sessions |
|
from website_sessions |
|
where created_at >= '2014-01-01' |
|
and created_at < '2014-11-05' |
|
group by 1 |
|
order by repeat_sessions desc; |
|
--========================================================================================== |
|
-- min, max, avg time between the first and the second session |
|
|
|
|
|
-- retrieve users with repeat sessions & created_at data |
|
DROP TEMPORARY TABLE IF EXISTS first_second_sessions; |
|
|
|
create temporary table first_second_sessions |
|
select |
|
first_session.created_at as first_created, |
|
first_session.user_id, |
|
first_session.website_session_id as first_sessions, |
|
website_sessions.website_session_id as second_sessions, |
|
website_sessions.created_at as second_created |
|
from |
|
( |
|
select |
|
website_session_id, |
|
user_id, |
|
created_at |
|
from website_sessions |
|
where created_at >='2014-01-01' |
|
and created_at < '2014-11-03' |
|
and is_repeat_session = 0 |
|
) as first_session |
|
left join website_sessions |
|
on website_sessions.user_id=first_session.user_id |
|
and website_sessions.is_repeat_session = 1 |
|
and website_sessions.website_session_id > first_session.website_session_id |
|
and website_sessions.created_at >= '2014-01-01' |
|
and website_sessions.created_at < '2014-11-03'; |
|
|
|
|
|
-- analyzing 'created_at' |
|
DROP TEMPORARY TABLE IF EXISTS pre_final; |
|
|
|
create temporary table pre_final |
|
select |
|
datediff(second_created, first_created) as days_first_second_session, |
|
user_id |
|
from |
|
( |
|
select |
|
first_created, |
|
first_sessions, |
|
user_id, |
|
min(second_created) as second_created, |
|
-- first session that is not new (repeat one) |
|
min(second_sessions) as second_session |
|
from first_second_sessions |
|
where second_sessions is not NULL |
|
group by 1,2,3 |
|
) as user_created; |
|
|
|
|
|
-- result |
|
select |
|
avg(days_first_second_session) as avg_days_first_second, |
|
min(days_first_second_session) as min_days_first_second, |
|
max(days_first_second_session) as max_days_first_second |
|
from pre_final; |
|
--========================================================================================== |
|
-- breakdown by UTM source, campaign, referring domain |
|
select |
|
utm_source, |
|
utm_campaign, |
|
http_referer, |
|
count(distinct web.website_session_id) as sessions |
|
from website_sessions as web |
|
where created_at < '2012-04-12' |
|
group by utm_source, utm_campaign, http_referer |
|
order by 4 desc; |
|
--========================================================================================== |
|
-- conversion rates from session to order by device type |
|
select |
|
device_type, |
|
count(distinct web.website_session_id) as sessions, |
|
count(distinct ord.order_id) as orders, |
|
count(distinct ord.order_id)/count(distinct web.website_session_id) as session_order_conv |
|
from website_sessions as web |
|
left join orders as ord |
|
on ord.website_session_id=web.website_session_id |
|
where web.created_at < '2012-05-11' |
|
and web.utm_campaign = 'nonbrand' |
|
and web.utm_source = 'gsearch' |
|
group by device_type; |
|
|
|
-- weekly trends for both desktop and mobile |
|
select |
|
min(date(web.created_at)) as week_start_date, |
|
count(distinct case when web.device_type = 'desktop' then web.website_session_id else NULL end) as dtop_sessions, |
|
count(distinct case when web.device_type = 'mobile' then web.website_session_id else NULL end) as mob_sessions |
|
from website_sessions as web |
|
where web.created_at < '2012-06-09' |
|
and web.created_at > '2012-05-19' |
|
and web.utm_source = 'gsearch' |
|
and web.utm_campaign = 'nonbrand' |
|
group by yearweek(web.created_at); |
|
--========================================================================================== |
|
-- conversion rate from session to order with at least 4% CVR |
|
select |
|
count(distinct a.website_session_id) as sessions, |
|
count(distinct b.order_id) as orders, |
|
count(distinct b.order_id)/count(distinct a.website_session_id) as session_order_conversion |
|
from website_sessions as a |
|
left join orders as b |
|
on b.website_session_id=a.website_session_id |
|
where a.created_at < '2012-04-14' and a.utm_source = 'gsearch' |
|
and utm_campaign = 'nonbrand'; |
|
--========================================================================================== |
|
-- |
|
select |
|
count(distinct website_session_id) as sessions, |
|
min(date(created_at)) as week_start, |
|
week(created_at), |
|
year(created_at) |
|
from website_sessions |
|
where website_session_id between 100000 and 115000 |
|
group by 4,3; |
|
|
|
-- COUNT with CASE inside can help to mimick Excel's Pivot. |
|
-- Use GROUP BY to define your row labels, and CASE to pivot to columns |
|
-- Below we want to know number of orders where 1 or 2 items were purchased and total of orders |
|
select |
|
primary_product_id, |
|
count(distinct case when items_purchased = 1 then order_id else NULL end) as orders_w_1_item, |
|
count(distinct case when items_purchased = 2 then order_id else NULL end) as orders_w_2_items, |
|
count(distinct order_id) as total_orders |
|
from orders |
|
where order_id between 31000 and 32000 |
|
group by 1; |
|
--========================================================================================== |
|
-- gsearch nonbrand trended session volme by week |
|
select |
|
date_format(web.created_at, '%Y-%m-%d') as week_start_date, |
|
count(distinct web.website_session_id) as sessions |
|
from website_sessions as web |
|
where web.created_at < '2012-05-10' and web.utm_source = 'gsearch' |
|
and web.utm_campaign = 'nonbrand' |
|
group by week_start_date |
|
order by week_start_date asc; |
|
|
|
select |
|
min(date(web.created_at)) as week_start_date, |
|
count(distinct web.website_session_id) as sessions |
|
from website_sessions as web |
|
where web.created_at < '2012-05-10' and web.utm_source = 'gsearch' |
|
and web.utm_campaign = 'nonbrand' |
|
group by year(web.created_at), week(web.created_at); |
|
/* yearweek() can be used*/ |
|
--========================================================================================== |
|
-- average website session volume by hour of day & by day week |
|
|
|
select |
|
hr, |
|
avg(case when wkday = 1 then website_sessions else NULL end) as tue, |
|
avg(case when wkday = 2 then website_sessions else NULL end) as wed, |
|
avg(case when wkday = 3 then website_sessions else NULL end) as thu, |
|
avg(case when wkday = 4 then website_sessions else NULL end) as fri, |
|
avg(case when wkday = 5 then website_sessions else NULL end) as sat, |
|
avg(case when wkday = 6 then website_sessions else NULL end) as sun |
|
from |
|
( |
|
select |
|
date(created_at) as date, |
|
weekday(created_at) as wkday, |
|
hour(created_at) as hr, |
|
count(distinct website_session_id) as website_sessions |
|
from website_sessions |
|
where created_at > '2012-09-15' and created_at < '2012-11-15' |
|
group by 1,2,3 |
|
) as date_table |
|
group by 1 |
|
order by 1; |
|
--========================================================================================== |
|
-- Analysis of business patterns will generate insights to help us |
|
-- maximize efficiency and anticipate future trends |
|
|
|
select |
|
website_session_id, |
|
created_at, |
|
hour(created_at) as hr, |
|
weekday(created_at) as wkday, -- 0 is Mnd, 1 is Tues |
|
CASE |
|
when weekday(created_at) = 0 then 'Monday' |
|
when weekday(created_at) = 1 then 'Tuesday' |
|
else 'other day' |
|
end as clean_weekday, |
|
quarter(created_at) as qtr, |
|
month(created_at) as month, |
|
date(created_at) as date, |
|
week(created_at) as wk |
|
from website_sessions |
|
where website_session_id between 150000 and 155000; |
|
--========================================================================================== |
|
-- a) have a gander at monthly & weekly volume patterns of 2012 |
|
-- b) session volume & order volume |
|
|
|
-- a |
|
select |
|
year(website_sessions.created_at), |
|
month(website_sessions.created_at), |
|
count(distinct website_sessions.website_session_id) as sessions, |
|
count(distinct orders.order_id) as orders |
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2012-01-01' |
|
and website_sessions.created_at < '2013-01-02' |
|
group by |
|
1,2 |
|
order by 1,2; |
|
|
|
-- b |
|
select |
|
min(date(website_sessions.created_at)) as week_start_date, |
|
count(distinct website_sessions.website_session_id) as sessions, |
|
count(distinct orders.order_id) as orders |
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2012-01-01' |
|
and website_sessions.created_at < '2013-01-02' |
|
group by |
|
yearweek(website_sessions.created_at); |
|
--========================================================================================== |
|
-- compare the month before vs the month after the change |
|
|
|
-- CTR from the '/cart' page, AVG products per Order, AOV, |
|
-- overall revenue per '/cart' page view |
|
|
|
|
|
-- relevant '/cart' pageviews & pertinent sessions |
|
DROP TEMPORARY TABLE IF EXISTS cross_sell; |
|
|
|
create temporary table cross_sell |
|
select |
|
website_pageview_id, |
|
website_session_id, |
|
CASE |
|
when created_at >= '2013-09-25' then 'post_cross_sell' |
|
when created_at < '2013-09-25' then 'pre_cross_sell' |
|
else 'Error' |
|
end as time_period |
|
from website_pageviews |
|
where created_at > '2013-08-25' |
|
and created_at < '2013-10-25' |
|
and pageview_url = '/cart'; |
|
|
|
-- check which '/cart' sessions reached another page |
|
DROP TEMPORARY TABLE IF EXISTS ship_views; |
|
|
|
create temporary table ship_views |
|
select |
|
cross_sell.website_session_id, |
|
cross_sell.time_period, |
|
min(website_pageviews.website_pageview_id) as min_pageview |
|
from cross_sell |
|
left join website_pageviews |
|
on website_pageviews.website_session_id=cross_sell.website_session_id |
|
and website_pageviews.website_pageview_id > cross_sell.website_pageview_id |
|
-- and website_pageviews.pageview_url = '/shipping' |
|
group by 1,2 |
|
having |
|
min_pageview is not NULL; |
|
-- so as to disect the ones who abandoned after '/cart' |
|
|
|
|
|
|
|
-- find orders which are associated with above '/cart' sessions |
|
DROP TEMPORARY TABLE IF EXISTS pre_post_sessions_orders; |
|
|
|
create temporary table pre_post_sessions_orders |
|
select |
|
orders.order_id, |
|
cross_sell.website_session_id, |
|
orders.items_purchased, |
|
orders.price_usd |
|
from cross_sell |
|
inner join orders |
|
on orders.website_session_id=cross_sell.website_session_id; |
|
|
|
-- final |
|
select |
|
time_period, |
|
count(distinct website_session_id) as cart_sessions, |
|
sum(clicked_to_another_page) as clickthorugh, |
|
sum(clicked_to_another_page)/count(distinct website_session_id) as cart_clickthorugh_rate, |
|
sum(items_purchased)/sum(placed_order) as products_per_order, |
|
sum(price_usd)/sum(placed_order) as AOV, |
|
sum(price_usd)/count(distinct website_session_id) as revenue_per_cart_session |
|
from |
|
( |
|
select |
|
cross_sell.time_period, |
|
cross_sell.website_session_id, |
|
(case when ship_views.website_session_id is NULL then 0 else 1 end) as clicked_to_another_page, |
|
(case when pre_post_sessions_orders.order_id is NULL then 0 else 1 end) as placed_order, |
|
pre_post_sessions_orders.items_purchased, |
|
pre_post_sessions_orders.price_usd |
|
from cross_sell |
|
left join ship_views |
|
on ship_views.website_session_id=cross_sell.website_session_id |
|
left join pre_post_sessions_orders |
|
on pre_post_sessions_orders.website_session_id=cross_sell.website_session_id |
|
order by |
|
cross_sell.website_session_id |
|
) as inner_table |
|
group by 1; |
|
--========================================================================================== |
|
-- Cross selling analysis: understanding which products users are most |
|
-- likely to purchase together, and offering smart product recommendations |
|
|
|
|
|
select |
|
count(distinct orders.order_id) as orders, |
|
orders.primary_product_id, |
|
count(distinct case when order_items.product_id = 1 then |
|
orders.order_id else NULL end) as cross_sell_product1, |
|
count(distinct case when order_items.product_id = 2 then |
|
orders.order_id else NULL end) as cross_sell_product2, |
|
count(distinct case when order_items.product_id = 3 then |
|
orders.order_id else NULL end) as cross_sell_product3 |
|
from orders |
|
left join order_items |
|
on order_items.order_id=orders.order_id |
|
and order_items.is_primary_item = 0 -- cross sell only |
|
where orders.order_id between 10000 and 11000 |
|
group by 2; |
|
--========================================================================================== |
|
-- Product sales help to understand: how each product contributes to the business and how |
|
-- product launches impact the overall portfolio |
|
|
|
-- orders: count(order_id) |
|
-- revenue: sum(price_usd) |
|
-- margin: sum(price_usd - cogs_usd) |
|
-- average order value: avg(price_usd) |
|
|
|
|
|
select |
|
primary_product_id, |
|
count(order_id) as orders, |
|
sum(price_usd) as revenue, |
|
sum(price_usd - cogs_usd) as margin, |
|
avg(price_usd) as aov |
|
from orders |
|
where order_id between 10000 and 11000 |
|
group by 1 |
|
order by 2 desc; |
|
--========================================================================================== |
|
-- pre-post analysis comparing the month before vs the month after |
|
-- in regard to session-to-order conversion rate, AOV, products per order, revenue per session |
|
|
|
select |
|
CASE |
|
when website_sessions.created_at >= '2013-12-12' then 'post_third_product' |
|
when website_sessions.created_at < '2013-12-12' then 'pre_third_product' |
|
else 'Error' |
|
end as time_period, |
|
count(distinct order_id)/count(distinct website_sessions.website_session_id) as conv_rate, |
|
sum(price_usd) as total_revenue, |
|
sum(items_purchased) as total_products_sold, |
|
sum(price_usd)/count(distinct order_id) as average_order_value, |
|
sum(items_purchased)/sum(case when order_id is not NULL then 1 else 0 end) as products_per_order, |
|
sum(price_usd)/count(distinct website_sessions.website_session_id) as revenue_per_session |
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2013-11-12' |
|
and website_sessions.created_at < '2014-01-12' |
|
group by |
|
CASE |
|
when website_sessions.created_at >= '2013-12-12' then 'post_third_product' |
|
when website_sessions.created_at < '2013-12-12' then 'pre_third_product' |
|
else 'Error' |
|
end; |
|
--========================================================================================== |
|
-- conversion funnels from each page to conversion |
|
|
|
-- comparision between the two conversion funnels for all website traffic |
|
|
|
|
|
|
|
-- select all pageviews for relevant sessions |
|
|
|
DROP TEMPORARY TABLE IF EXISTS sessions_urls; |
|
|
|
create temporary table sessions_urls |
|
select |
|
website_pageviews.pageview_url as url, |
|
website_sessions.website_session_id, |
|
website_pageviews.website_pageview_id |
|
from website_sessions |
|
left join website_pageviews |
|
on website_pageviews.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2013-01-06' |
|
and website_sessions.created_at < '2013-04-10' |
|
and pageview_url in ('/the-original-mr-fuzzy', '/the-forever-love-bear'); |
|
|
|
|
|
-- scrutinize which pageview_url to look for (it'll be a demo which will be incorporated further) |
|
select distinct |
|
website_pageviews.pageview_url |
|
from sessions_urls |
|
left join website_pageviews |
|
on website_pageviews.website_session_id=sessions_urls.website_session_id |
|
and website_pageviews.website_pageview_id > sessions_urls.website_pageview_id; |
|
-- enables to see which pageviews (urls in select) to look for |
|
|
|
-- => next |
|
DROP TEMPORARY TABLE IF EXISTS products; |
|
|
|
create temporary table products |
|
select |
|
website_session_id, |
|
CASE |
|
when url = '/the-original-mr-fuzzy' then 'mr_fuzzy' |
|
when url = '/the-forever-love-bear' then 'lovebear' |
|
else 'Error' |
|
end as product_seen, |
|
max(cart) as cart, |
|
max(shipping) as shipping, |
|
max(billing) as billing, |
|
max(thank_you) as thanks |
|
from |
|
( |
|
select |
|
sessions_urls.website_session_id, |
|
sessions_urls.url, |
|
case when website_pageviews.pageview_url = '/cart' then 1 else 0 end as cart, |
|
case when website_pageviews.pageview_url = '/shipping' then 1 else 0 end as shipping, |
|
case when website_pageviews.pageview_url = '/billing-2' then 1 else 0 end as billing, |
|
case when website_pageviews.pageview_url = '/thank-you-for-your-order' then 1 else 0 end as thank_you |
|
from sessions_urls |
|
left join website_pageviews |
|
on website_pageviews.website_session_id=sessions_urls.website_session_id |
|
and website_pageviews.website_pageview_id > sessions_urls.website_pageview_id |
|
order by |
|
sessions_urls.website_session_id, |
|
website_pageviews.created_at |
|
) as inner_table |
|
group by website_session_id, |
|
CASE |
|
when url = '/the-original-mr-fuzzy' then 'mr_fuzzy' |
|
when url = '/the-forever-love-bear' then 'lovebear' |
|
else 'Error' |
|
end; |
|
|
|
-- final numbers |
|
|
|
select |
|
product_seen, |
|
count(distinct website_session_id), |
|
count(distinct case when cart = 1 then website_session_id else NULL end) as to_cart, |
|
count(distinct case when shipping = 1 then website_session_id else NULL end) as to_shipping, |
|
count(distinct case when billing = 1 then website_session_id else NULL end) as to_billing, |
|
count(distinct case when thanks = 1 then website_session_id else NULL end) as to_thanks |
|
from products |
|
group by product_seen; |
|
|
|
|
|
-- final ratio |
|
|
|
select |
|
product_seen, |
|
count(distinct case when cart = 1 then website_session_id else NULL end)/ |
|
count(distinct website_session_id) as product_page_clickthrough, |
|
|
|
count(distinct case when shipping = 1 then website_session_id else NULL end)/ |
|
count(distinct case when cart = 1 then website_session_id else NULL end) as cart_clickthrough, |
|
|
|
count(distinct case when billing = 1 then website_session_id else NULL end)/ |
|
count(distinct case when shipping = 1 then website_session_id else NULL end) as shipping_clickthrough, |
|
|
|
count(distinct case when thanks = 1 then website_session_id else NULL end)/ |
|
count(distinct case when billing = 1 then website_session_id else NULL end) as billing_clickthrough |
|
from products |
|
group by 1; |
|
--========================================================================================== |
|
-- monthly order volume, overall conversion rate, revenue per seesion, |
|
-- breakdown of sales by product |
|
|
|
select |
|
min(date(website_sessions.created_at)) as month_date, |
|
count(distinct order_id) as orders, |
|
count(distinct order_id)/count(distinct website_sessions.website_session_id) as conv_rate, |
|
sum(price_usd)/count(distinct website_sessions.website_session_id) as revenue_per_session, |
|
count(distinct case when primary_product_id = 1 then order_id else NULL end) as product_one_orders, |
|
count(distinct case when primary_product_id = 2 then order_id else NULL end) as product_two_orders |
|
from orders |
|
right join website_sessions |
|
on website_sessions.website_session_id=orders.website_session_id |
|
where website_sessions.created_at > '2012-04-01' |
|
and website_sessions.created_at < '2013-04-05' |
|
group by |
|
year(website_sessions.created_at), |
|
month(website_sessions.created_at); |
|
--========================================================================================== |
|
-- monthly trends to date for number of sales, total revenue and total margin generated |
|
|
|
select |
|
min(date(created_at)) as month_date, |
|
count(distinct order_id) as number_of_sales, |
|
sum(price_usd) as total_revenue, |
|
sum(price_usd - cogs_usd) as total_margin |
|
from orders |
|
where created_at < '2013-01-04' |
|
group by |
|
month(created_at); |
|
--========================================================================================== |
|
-- weekly trended session volume & comparision of gsearch to bsearch |
|
select |
|
min(date(created_at)) as week_start_date, |
|
count(case when utm_source = 'gsearch' then website_session_id else NULL end) as gsearch_sessions, |
|
count(case when utm_source = 'bsearch' then website_session_id else NULL end) as bsearch_sessions |
|
from website_sessions |
|
where created_at > '2012-08-22' and created_at < '2012-11-29' |
|
and utm_campaign = 'nonbrand' |
|
group by |
|
yearweek(created_at); |
|
--========================================================================================== |
|
-- nonbrand conversion rates from session to order for gsearch & bsearch |
|
-- + slice by device_type |
|
|
|
select |
|
device_type, |
|
utm_source, |
|
count(distinct website_sessions.website_session_id) as sessions, |
|
count(distinct orders.order_id) as orders, |
|
count(distinct orders.order_id)/ |
|
count(distinct website_sessions.website_session_id) as conversion_rate |
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2012-08-22' and website_sessions.created_at < '2012-09-18' |
|
and utm_campaign = 'nonbrand' |
|
and utm_source in ('gsearch', 'bsearch') |
|
group by |
|
1,2; |
|
--========================================================================================== |
|
-- pull organic search, direct type in, paid brand search sessions by month |
|
-- + % of paid search nonbrand |
|
|
|
select |
|
min(date(created_at)) as month_year, |
|
count(case when utm_campaign = 'nonbrand' then website_session_id else NULL end) as nonbrand, |
|
count(case when utm_campaign = 'brand' then website_session_id else NULL end) as brand, |
|
count(case when utm_campaign = 'brand' then website_session_id else NULL end)/ |
|
count(case when utm_campaign = 'nonbrand' then website_session_id else NULL end) as br_perc_nonbr, |
|
|
|
count(case when http_referer is NULL and utm_source is NULL then website_session_id else NULL end) as direct, |
|
count(case when http_referer is NULL and utm_source is NULL then website_session_id else NULL end)/ |
|
count(case when utm_campaign = 'nonbrand' then website_session_id else NULL end) as direct_perc_nonbrand, |
|
|
|
count(case when http_referer is not NULL and utm_source is NULL then website_session_id else NULL end) as organic, |
|
count(case when http_referer is not NULL and utm_source is NULL then website_session_id else NULL end)/ |
|
count(case when utm_campaign = 'nonbrand' then website_session_id else NULL end) as organic_perc_nonbrand |
|
from website_sessions |
|
where created_at < '2012-12-23' |
|
group by |
|
month(created_at); |
|
|
|
/* roughly equals to below query. In below one I specify in particular which 'http_referer' to use */ |
|
|
|
select |
|
min(date(created_at)) as month_year, |
|
count(distinct case when channel_group = 'paid_nonbrand' then website_session_id else NULL end) as nonbrand, |
|
count(distinct case when channel_group = 'paid_brand' then website_session_id else NULL end) as brand, |
|
count(distinct case when channel_group = 'paid_brand' then website_session_id else NULL end)/ |
|
count(distinct case when channel_group = 'paid_nonbrand' then website_session_id else NULL end) as br_perc_nonbr, |
|
|
|
count(distinct case when channel_group = 'direct_type' then website_session_id else NULL end) as direct, |
|
count(distinct case when channel_group = 'direct_type' then website_session_id else NULL end)/ |
|
count(distinct case when channel_group = 'paid_nonbrand' then website_session_id else NULL end) as direct_perc_nonbrand, |
|
|
|
count(distinct case when channel_group = 'organic_search' then website_session_id else NULL end) as organic, |
|
count(distinct case when channel_group = 'organic_search' then website_session_id else NULL end)/ |
|
count(distinct case when channel_group = 'paid_nonbrand' then website_session_id else NULL end) as organic_perc_nonbrand |
|
from |
|
( |
|
select |
|
website_session_id, |
|
created_at, |
|
case |
|
when utm_source is NULL and http_referer in ('https://www.gsearch.com', 'https://www.bsearch.com') |
|
then 'organic_search' |
|
when utm_source is NULL and http_referer is NULL then 'direct_type' |
|
when utm_campaign = 'nonbrand' then 'paid_nonbrand' |
|
when utm_campaign = 'brand' then 'paid_brand' |
|
end as channel_group |
|
from website_sessions |
|
where created_at < '2012-12-23' |
|
) as inner_table |
|
group by |
|
month(created_at); |
|
--========================================================================================== |
|
-- branded or direct traffic speaks about how well brand is doing with consumers |
|
-- and how well brand drives business |
|
|
|
select |
|
CASE |
|
when http_referer is NULL then 'direct_typing' |
|
when http_referer = 'https://www.gsearch.com' then 'gsearch_organic' |
|
when http_referer = 'https://www.bsearch.com' then 'bsearch_organic' |
|
else 'other' |
|
end, |
|
count(distinct website_session_id) as sessions |
|
from website_sessions |
|
where website_session_id between 100000 and 115000 |
|
and utm_source is NULL |
|
group by 1 |
|
order by 2 desc; |
|
|
|
-- utm_source is paid traffic if not NULL else (direct traffic) |
|
|
|
-- Considering utm_source is NULL: |
|
-- http_referer: the website that sent us the traffic. If NULL -> direct typing |
|
-- if not NULL -> organic search |
|
|
|
|
|
-- including paid search traffic |
|
|
|
select |
|
CASE |
|
when http_referer is NULL then 'direct_typing' |
|
when http_referer = 'https://www.gsearch.com' and utm_source is NULL then 'gsearch_organic' |
|
when http_referer = 'https://www.bsearch.com' and utm_source is NULL then 'bsearch_organic' |
|
else 'other' |
|
end, |
|
count(distinct website_session_id) as sessions |
|
from website_sessions |
|
where website_session_id between 100000 and 115000 |
|
group by 1 |
|
order by 2 desc; |
|
--========================================================================================== |
|
-- pull overall session-to-order conversion rate trends for the channels |
|
-- by quarter + notes of periods with surge-like improvement |
|
|
|
select |
|
year(website_sessions.created_at) as year, |
|
quarter(website_sessions.created_at) as quarter, |
|
|
|
count(case when utm_campaign = 'nonbrand' and utm_source = 'gsearch' |
|
then orders.order_id else NULL end)/ |
|
count(case when utm_campaign = 'nonbrand' and utm_source = 'gsearch' |
|
then website_sessions.website_session_id else NULL end) as nonbr_gs_cvr, |
|
|
|
count(case when utm_campaign = 'nonbrand' and utm_source = 'bsearch' |
|
then orders.order_id else NULL end)/ |
|
count(case when utm_campaign = 'nonbrand' and utm_source = 'bsearch' |
|
then website_sessions.website_session_id else NULL end) as nonbr_bs_cvr, |
|
|
|
count(case when utm_campaign = 'brand' then orders.order_id else NULL end)/ |
|
count(case when utm_campaign = 'brand' then |
|
website_sessions.website_session_id else NULL end) as branded_cvr, |
|
|
|
count(case when http_referer is not NULL and utm_source is NULL |
|
then orders.order_id else NULL end)/ |
|
count(case when http_referer is not NULL and utm_source is NULL then |
|
website_sessions.website_session_id else NULL end) as organic_cvr, |
|
|
|
count(case when http_referer is NULL and utm_source is NULL |
|
then orders.order_id else NULL end)/ |
|
count(case when http_referer is NULL and utm_source is NULL then |
|
website_sessions.website_session_id else NULL end) as direct_in_cvr |
|
|
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at < '2015-03-20' |
|
group by 1,2 |
|
order by 1,2; |
|
--========================================================================================== |
|
-- quarterly figures for session-to-order CVR, revenue per order, revenue per session |
|
|
|
select |
|
year(website_sessions.created_at), |
|
quarter(website_sessions.created_at), |
|
count(orders.order_id)/ |
|
count(website_sessions.website_session_id) as session_order_conv_rate, |
|
sum(price_usd)/count(orders.order_id) as revenue_per_order, |
|
sum(price_usd)/ |
|
count(website_sessions.website_session_id) as revenue_per_session |
|
from website_sessions |
|
left join orders |
|
on orders.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at < '2015-03-20' |
|
group by |
|
year(website_sessions.created_at), |
|
quarter(website_sessions.created_at) |
|
order by 1,2; |
|
--========================================================================================== |
|
-- pull monthly trending for revenue and margin by product, along with |
|
-- total sales and revenue + notes about seasonality |
|
|
|
select |
|
year(orders.created_at) as year, |
|
month(orders.created_at) as month, |
|
|
|
sum(order_items.price_usd - order_items.cogs_usd) as total_margin, |
|
sum(order_items.price_usd) as total_revenue, |
|
count(orders.order_id) as total_sales, |
|
|
|
sum(case when order_items.product_id = 1 then order_items.price_usd else NULL end) as first_product_rev, |
|
sum(case when order_items.product_id = 2 then order_items.price_usd else NULL end) as second_product_rev, |
|
sum(case when order_items.product_id = 3 then order_items.price_usd else NULL end) as third_product_rev, |
|
sum(case when order_items.product_id = 4 then order_items.price_usd else NULL end) as fourth_product_rev, |
|
|
|
sum(case when order_items.product_id = 1 then order_items.price_usd - order_items.cogs_usd |
|
else NULL end) as first_product_margin, |
|
sum(case when order_items.product_id = 2 then order_items.price_usd - order_items.cogs_usd |
|
else NULL end) as second_product_margin, |
|
sum(case when order_items.product_id = 3 then order_items.price_usd - order_items.cogs_usd |
|
else NULL end) as third_product_margin, |
|
sum(case when order_items.product_id = 4 then order_items.price_usd - order_items.cogs_usd |
|
else NULL end) as fourth_product_margin, |
|
|
|
count(case when orders.primary_product_id = 1 then orders.order_id else NULL end) as product_one_orders, |
|
count(case when orders.primary_product_id = 2 then orders.order_id else NULL end) as product_two_orders, |
|
count(case when orders.primary_product_id = 3 then orders.order_id else NULL end) as product_three_orders, |
|
count(case when orders.primary_product_id = 4 then orders.order_id else NULL end) as product_four_orders |
|
|
|
from order_items |
|
inner join orders |
|
on orders.order_id=order_items.order_id |
|
where orders.created_at < '2015-03-20' |
|
group by 1,2 |
|
order by 1,2; |
|
--========================================================================================== |
|
use mavenfuzzyfactory; |
|
|
|
-- revenue per billing page session |
|
|
|
select |
|
count(distinct website_session_id) as sessions, |
|
page_url, |
|
sum(price_usd)/count(distinct website_session_id) as revenue_per_billing_page |
|
from |
|
( |
|
select |
|
website_pageviews.website_session_id, |
|
website_pageviews.pageview_url as page_url, |
|
orders.order_id, |
|
orders.price_usd |
|
from website_pageviews |
|
left join orders |
|
on orders.website_session_id=website_pageviews.website_session_id |
|
where website_pageviews.created_at > '2012-09-10' |
|
and website_pageviews.created_at < '2012-11-10' |
|
and website_pageviews.pageview_url in ('/billing', '/billing-2') |
|
) as first |
|
group by page_url; |
|
|
|
|
|
-- number of billing sessions per month |
|
select |
|
count(distinct website_session_id) as session |
|
from website_pageviews |
|
where created_at > '2012-10-27' and created_at < '2012-11-27' |
|
and pageview_url in ('/billing', '/billing-2'); |
|
|
|
/* 1191 is the total amount of billed sessions */ |
|
--========================================================================================== |
|
use mavenfuzzyfactory; |
|
|
|
-- full conversion funnel from each of the two pages to orders |
|
DROP TEMPORARY TABLE IF EXISTS conversion_temp; |
|
|
|
create temporary table conversion_temp |
|
|
|
select |
|
Move.website_session_id, |
|
max(home) as home_page, |
|
max(custom_home) as custom_home_page, |
|
max(products_page) as products_page, |
|
max(mr_fuzzy) as fuzzy_page, |
|
max(cart) as cart_page, |
|
max(shipping) as shipping_page, |
|
max(billing) as billing_page, |
|
max(thanks) as thanks_page |
|
from |
|
( |
|
select |
|
website_sessions.website_session_id, |
|
website_pageviews.pageview_url, |
|
(case when pageview_url = '/home' then 1 else 0 end) as home, |
|
(case when pageview_url = '/lander-1' then 1 else 0 end) as custom_home, |
|
(case when pageview_url = '/products' then 1 else 0 end) as products_page, |
|
(case when pageview_url = '/the-original-mr-fuzzy' then 1 else 0 end) as mr_fuzzy, |
|
(case when pageview_url = '/cart' then 1 else 0 end) as cart, |
|
(case when pageview_url = '/shipping' then 1 else 0 end) as shipping, |
|
(case when pageview_url = '/billing' then 1 else 0 end) as billing, |
|
(case when pageview_url = '/thank-you-for-your-order' then 1 else 0 end) as thanks |
|
from website_sessions |
|
inner join website_pageviews |
|
on website_pageviews.website_session_id=website_sessions.website_session_id |
|
where website_sessions.created_at > '2012-06-19' and website_sessions.created_at < '2012-07-28' |
|
and utm_source = 'gsearch' |
|
and utm_campaign = 'nonbrand' |
|
order by |
|
website_sessions.website_session_id, |
|
website_pageviews.created_at |
|
) as Move |
|
group by 1; |
|
|
|
|
|
-- 1: exact conversion; 2: exact conversion rate |
|
|
|
select |
|
count(distinct website_session_id) as sessions, |
|
case |
|
when home_page = 1 then 'home_page_seen' |
|
when custom_home_page = 1 then 'custom_home_page_seen' |
|
else 'without home page' |
|
end as Start_Page, |
|
count(distinct case when products_page = 1 then website_session_id else NULL end) as to_products_page, |
|
count(distinct case when fuzzy_page = 1 then website_session_id else NULL end) as to_fuzzy_page, |
|
count(distinct case when cart_page = 1 then website_session_id else NULL end) as to_cart_page, |
|
count(distinct case when shipping_page = 1 then website_session_id else NULL end) as to_shipping_page, |
|
count(distinct case when billing_page = 1 then website_session_id else NULL end) as to_billing_page, |
|
count(distinct case when thanks_page = 1 then website_session_id else NULL end) as to_thank_you_page |
|
|
|
from conversion_temp |
|
group by 2; |
|
|
|
|
|
|
|
select |
|
count(distinct website_session_id) as sessions, |
|
case |
|
when home_page = 1 then 'home_page_seen' |
|
when custom_home_page = 1 then 'custom_home_page_seen' |
|
else 'without home page' |
|
end as Start_Page, |
|
|
|
count(distinct case when products_page = 1 then website_session_id else NULL end)/ |
|
count(distinct website_session_id) as start_page_clickthrough, |
|
|
|
count(distinct case when fuzzy_page = 1 then website_session_id else NULL end)/ |
|
count(distinct case when products_page = 1 then website_session_id else NULL end) as products_clickthrough_rate, |
|
|
|
count(distinct case when cart_page = 1 then website_session_id else NULL end)/ |
|
count(distinct case when fuzzy_page = 1 then website_session_id else NULL end) as fuzzy_clickthrough_rate, |
|
|
|
count(distinct case when shipping_page = 1 then website_session_id else NULL end)/ |
|
count(distinct case when cart_page = 1 then website_session_id else NULL end) as cart_clickthrough_rate, |
|
|
|
count(distinct case when billing_page = 1 then website_session_id else NULL end)/ |
|
count(distinct case when shipping_page = 1 then website_session_id else NULL end) as shipping_clickthrough_rate, |
|
|
|
count(distinct case when thanks_page = 1 then website_session_id else NULL end)/ |
|
count(distinct case when billing_page = 1 then website_session_id else NULL end) as billing_clickthrough_rate |
|
|
|
from conversion_temp |
|
group by 2; |
|
--========================================================================================== |
|
use mavenfuzzyfactory; |
|
|
|
-- see what is the first website pageview id |
|
select |
|
min(website_pageview_id) |
|
from website_pageviews |
|
where pageview_url = '/lander-1'; |
|
|
|
/* => 23505 & the span of the test: 2012-06-19 to 2012-07-28 */ |
|
|
|
-- first pageview id and concurrent session |
|
DROP TEMPORARY TABLE IF EXISTS pageview_sessions; |
|
|
|
create temporary table pageview_sessions |
|
select |
|
website_pageviews.website_session_id, |
|
min(website_pageviews.website_pageview_id) as min_pageview_id |
|
from website_sessions |
|
inner join website_pageviews |
|
on website_pageviews.website_session_id=website_sessions.website_session_id |
|
and website_pageviews.created_at > '2012-06-19' and website_pageviews.created_at < '2012-07-28' |
|
and website_pageviews.website_pageview_id >= 23505 |
|
and website_sessions.utm_source = 'gsearch' |
|
and website_sessions.utm_campaign = 'nonbrand' |
|
group by |
|
website_pageviews.website_session_id; |
|
|
|
|
|
-- show landing pages. 2 options: /home or /lander-1 + add orders if exits else NULL |
|
DROP TEMPORARY TABLE IF EXISTS sessions_landing_pages; |
|
|
|
create temporary table sessions_landing_pages |
|
|
|
select |
|
website_pageviews.pageview_url as landing_url, |
|
pageview_sessions.website_session_id, |
|
orders.order_id |
|
from pageview_sessions |
|
left join website_pageviews |
|
on website_pageviews.website_pageview_id=pageview_sessions.min_pageview_id |
|
left join orders |
|
on orders.website_session_id=pageview_sessions.website_session_id |
|
where website_pageviews.pageview_url in ('/home', '/lander-1'); |
|
|
|
-- find conversion on two pages |
|
select |
|
landing_url, |
|
count(distinct website_session_id) as sessions, |
|
count(distinct order_id) as orders, |
|
count(distinct order_id)/count(distinct website_session_id) as order_session_ratio |
|
from sessions_landing_pages |
|
group by 1; |
|
|
|
|
|
|
|
-- then last (aka max) session_id should be found with url = '/home' |
|
select |
|
max(website_sessions.website_session_id) as latest_gsearch_home_view |
|
from website_sessions |
|
left join website_pageviews |
|
on website_pageviews.website_session_id=website_sessions.website_session_id |
|
where utm_source = 'gsearch' |
|
and utm_campaign = 'nonbrand' |
|
and pageview_url = '/home' |
|
and website_sessions.created_at < '2012-11-27'; |
|
/* 17145: after the received value all other id's went elsewhere than /home */ |
|
|
|
|
|
select |
|
count(distinct website_session_id) as sessions |
|
from website_sessions |
|
where created_at < '2012-11-27' |
|
and website_session_id > 17145 |
|
and utm_source = 'gsearch' |
|
and utm_campaign = 'nonbrand'; |
|
|
|
/* result will be amount of sessions after the test has been launched: 23040 */ |
|
|
|
from the conversion of two pages |
|
=> abs(0.031 - 0.041) = 0.01 increase in conversion rate from ordinary /home to /lander |
|
|
|
=> 0.01 * 23040 = 230 |
|
It means 230 increase of orders overall |
|
--========================================================================================== |
|
select array_agg(concat(1,'::', 2)::text); |
|
|
|
SELECT ('===>'||table_name||' :: '||column_name)::text from information_schema.columns |
|
where table_schema='public'; |
|
|
|
select array(SELECT ('===>'||table_name||' :: '||column_name)::text) from information_schema.columns |
|
where table_schema='public' |
|
|
|
select ARRAY_AGG(COALESCE(e.name::text,(CHR(32))))::text from employee e; |
|
|
|
select ARRAY_AGG(COALESCE(attname::text,(CHR(32))))::text FROM pg_attribute b JOIN pg_class a ON a.oid=b.attrelid JOIN pg_type c ON c.oid=b.atttypid JOIN pg_namespace d ON a.relnamespace=d.oid WHERE b.attnum>0 |
|
--AND a.relname='<table>' AND nspname='<database>' |
|
|
|
select table_name FROM information_schema.tables |
|
|
|
select * from pg_database; |
|
|
|
select table_name||':::'||column_name::text from information_schema.columns |
|
|
|
select * from pg_shadow; |
|
--========================================================================================== |
|
SELECT table_name FROM information_schema.tables |
|
WHERE table_schema NOT IN ('information_schema', 'pg_catalog') |
|
AND table_schema IN('public', 'myschema'); |
|
|
|
SELECT pg_database.datname, pg_size_pretty(pg_database_size(pg_database.datname)) AS size FROM pg_database; |
|
|
|
SELECT pg_size_pretty(pg_database_size(current_database())); |
|
|
|
select table_name, |
|
pg_size_pretty(total_size) as total_size, |
|
pg_size_pretty(table_size) as table_size, |
|
pg_size_pretty(indexes_size) as indexes_size, |
|
pg_size_pretty(toast_size) as toast_size |
|
from ( |
|
select c.oid::regclass as table_name, |
|
pg_total_relation_size(c.oid) as total_size, |
|
pg_table_size(c.oid) as table_size, |
|
pg_indexes_size(c.oid) as indexes_size, |
|
coalesce(pg_total_relation_size(c.reltoastrelid), 0) as toast_size |
|
from pg_class c |
|
left join pg_namespace n on n.oid = c.relnamespace |
|
where c.relkind = 'r' |
|
and n.nspname = 'public'::text |
|
order by c.relname::text |
|
) as tables; |
|
|
|
select pg_size_pretty(pg_total_relation_size('public.employee')); |
|
|
|
select |
|
coalesce(t.spcname, 'pg_default') as tablespace, |
|
n.nspname ||'.'||c.relname as table, |
|
(select count(*) from pg_index i where i.indrelid=c.oid) as index_count, |
|
pg_size_pretty(pg_relation_size(c.oid)) as t_size, |
|
pg_size_pretty(pg_indexes_size(c.oid)) as i_size |
|
from pg_class c |
|
join pg_namespace n on c.relnamespace = n.oid |
|
left join pg_tablespace t on c.reltablespace = t.oid |
|
where c.reltype != 0 and n.nspname = 'public' |
|
order by (pg_relation_size(c.oid),pg_indexes_size(c.oid)) desc; |
|
|
|
SELECT relname, relpages FROM pg_class ORDER BY relpages DESC LIMIT 1; |
|
|
|
SELECT datname,usename,client_addr,client_port FROM pg_stat_activity; |
|
|
|
SELECT datname FROM pg_stat_activity WHERE usename = 'devuser'; |
|
|
|
select rolname, rolconnlimit from pg_roles; |
|
|
|
SELECT r.rolname, r.rolsuper, r.rolinherit, |
|
r.rolcreaterole, r.rolcreatedb, r.rolcanlogin, |
|
r.rolconnlimit, r.rolvaliduntil, |
|
ARRAY(SELECT b.rolname |
|
FROM pg_catalog.pg_auth_members m |
|
JOIN pg_catalog.pg_roles b ON (m.roleid = b.oid) |
|
WHERE m.member = r.oid) as memberof |
|
, pg_catalog.shobj_description(r.oid, 'pg_authid') AS description |
|
, r.rolreplication |
|
FROM pg_catalog.pg_roles r |
|
ORDER BY 1; |
|
|
|
select relname as objectname, pg_stat_get_live_tuples(c.oid) as livetuples, pg_stat_get_dead_tuples(c.oid) as deadtuples |
|
from pg_class c where relname = 'order_item'; |
|
|
|
select * from pg_stat_all_tables where relname='employee'; |
|
|
|
select table_name, |
|
c.column_name, c.data_type, coalesce(c.numeric_precision, c.character_maximum_length) as maximum_length, c.numeric_scale |
|
from pg_catalog.pg_statio_all_tables as st |
|
inner join pg_catalog.pg_description pgd on (pgd.objoid=st.relid) |
|
right outer join information_schema.columns c on (pgd.objsubid=c.ordinal_position and c.table_schema=st.schemaname and c.table_name=st.relname) |
|
where table_schema = 'public'; |
|
|
|
select psat.relid::regclass::text as table_name, |
|
psat.schemaname as schema_name |
|
from pg_catalog.pg_stat_all_tables psat |
|
where |
|
(obj_description(psat.relid) is null or length(trim(obj_description(psat.relid))) = 0) |
|
and position('flyway_schema_history' in psat.relid::regclass::text) <= 0 |
|
and psat.schemaname not in ('information_schema', 'pg_catalog', 'pg_toast') |
|
order by 1; |
|
|
|
select t.oid::regclass::text as table_name, |
|
col.attname::text as column_name |
|
from pg_catalog.pg_class t |
|
join pg_catalog.pg_namespace nsp on nsp.oid = t.relnamespace |
|
join pg_catalog.pg_attribute col on (col.attrelid = t.oid) |
|
where t.relkind = 'r' and |
|
col.attnum > 0 and /* to filter out system columns such as oid, ctid, xmin, xmax, etc.*/ |
|
--nsp.nspname = :schema_name_param::text and |
|
position('flyway_schema_history' in t.oid::regclass::text) <= 0 and |
|
nsp.nspname not in ('information_schema', 'pg_catalog', 'pg_toast') and |
|
col_description(t.oid, col.attnum) is null |
|
order by 1, 2; |
|
|
|
select |
|
x.indrelid::regclass as table_name, |
|
x.indexrelid::regclass as index_name, |
|
x.indisunique as is_unique, |
|
x.indisvalid as is_valid, |
|
x.indnatts as columns_count, |
|
pg_get_indexdef(x.indexrelid) as index_definition |
|
from |
|
pg_catalog.pg_index x |
|
join pg_catalog.pg_stat_all_indexes psai on x.indexrelid = psai.indexrelid |
|
where |
|
psai.schemaname = 'public'::text |
|
and x.indexrelid::regclass::text = 'target_index_name'::text; |
|
|
|
select |
|
d.classid::regclass as owning_object_type, |
|
d.objid::regclass as owning_object, |
|
d.refobjid::regclass as dependent_object, |
|
a.attname as dependent_column, |
|
d.deptype -- see https://www.postgresql.org/docs/current/catalog-pg-depend.html |
|
from pg_catalog.pg_depend d |
|
left join pg_catalog.pg_attribute a on d.refobjid = a.attrelid and d.refobjsubid = a.attnum |
|
where |
|
refobjid = 'target_table_name'::regclass and |
|
a.attname = 'target_column_name'; |
|
|
|
SELECT |
|
pg_class.relname, |
|
pg_size_pretty(pg_class.reltuples::BIGINT) AS rows_in_bytes, |
|
pg_class.reltuples AS num_rows, |
|
COUNT(indexname) AS number_of_indexes, |
|
CASE WHEN x.is_unique = 1 THEN 'Y' |
|
ELSE 'N' |
|
END AS UNIQUE, |
|
SUM(CASE WHEN number_of_columns = 1 THEN 1 |
|
ELSE 0 |
|
END) AS single_column, |
|
SUM(CASE WHEN number_of_columns IS NULL THEN 0 |
|
WHEN number_of_columns = 1 THEN 0 |
|
ELSE 1 |
|
END) AS multi_column |
|
FROM pg_namespace |
|
LEFT OUTER JOIN pg_class ON pg_namespace.oid = pg_class.relnamespace |
|
LEFT OUTER JOIN |
|
(SELECT indrelid, |
|
MAX(CAST(indisunique AS INTEGER)) AS is_unique |
|
FROM pg_index |
|
GROUP BY indrelid) x |
|
ON pg_class.oid = x.indrelid |
|
LEFT OUTER JOIN |
|
( SELECT c.relname AS ctablename, ipg.relname AS indexname, x.indnatts AS number_of_columns FROM pg_index x |
|
JOIN pg_class c ON c.oid = x.indrelid |
|
JOIN pg_class ipg ON ipg.oid = x.indexrelid ) |
|
AS foo |
|
ON pg_class.relname = foo.ctablename |
|
WHERE |
|
pg_namespace.nspname='public' |
|
AND pg_class.relkind = 'r' |
|
GROUP BY pg_class.relname, pg_class.reltuples, x.is_unique |
|
ORDER BY 2; |
|
|
|
SELECT |
|
t.tablename, |
|
indexname, |
|
c.reltuples AS num_rows, |
|
pg_size_pretty(pg_relation_size(quote_ident(t.tablename)::text)) AS table_size, |
|
pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size, |
|
CASE WHEN indisunique THEN 'Y' |
|
ELSE 'N' |
|
END AS UNIQUE, |
|
idx_scan AS number_of_scans, |
|
idx_tup_read AS tuples_read, |
|
idx_tup_fetch AS tuples_fetched |
|
FROM pg_tables t |
|
LEFT OUTER JOIN pg_class c ON t.tablename=c.relname |
|
LEFT OUTER JOIN |
|
( SELECT c.relname AS ctablename, ipg.relname AS indexname, x.indnatts AS number_of_columns, idx_scan, idx_tup_read, idx_tup_fetch, indexrelname, indisunique |
|
FROM pg_index x |
|
JOIN pg_class c ON c.oid = x.indrelid |
|
JOIN pg_class ipg ON ipg.oid = x.indexrelid |
|
JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid AND psai.schemaname = 'public' ) |
|
AS foo |
|
ON t.tablename = foo.ctablename |
|
WHERE t.schemaname='public' |
|
ORDER BY 1,2; |
|
|
|
SELECT |
|
c.relname AS table_name, |
|
ipg.relname AS index_name, |
|
pg_size_pretty(pg_relation_size(quote_ident(indexrelname)::text)) AS index_size |
|
FROM pg_index x |
|
JOIN pg_class c ON c.oid = x.indrelid |
|
JOIN pg_class ipg ON ipg.oid = x.indexrelid |
|
JOIN pg_stat_all_indexes psai ON x.indexrelid = psai.indexrelid AND psai.schemaname = 'public' |
|
ORDER BY pg_relation_size(quote_ident(indexrelname)::text) desc nulls last |
|
LIMIT 10; |
|
|
|
select tablename as table_name |
|
from pg_tables |
|
where |
|
schemaname = 'public'::text and |
|
tablename not in ( |
|
select c.conrelid::regclass::text as table_name |
|
from pg_constraint c |
|
where contype = 'p') and |
|
tablename not in ('databasechangelog') |
|
order by tablename; |
|
|
|
select c.conrelid::regclass as table_name, string_agg(col.attname, ', ' order by u.attposition) as columns, |
|
c.conname as constraint_name, pg_get_constraintdef(c.oid) as definition |
|
from pg_constraint c |
|
join lateral unnest(c.conkey) with ordinality as u(attnum, attposition) on true |
|
join pg_class t on (c.conrelid = t.oid) |
|
join pg_attribute col on (col.attrelid = t.oid and col.attnum = u.attnum) |
|
where contype = 'p' |
|
group by c.conrelid, c.conname, c.oid |
|
order by (c.conrelid::regclass)::text, columns; |
|
|
|
select data.id, case when data.id % 2 = 0 then now()::text else null end, case when data.id % 2 = 0 then 'test_string'::text else null end |
|
from generate_series(1, 100) as data(id); |
|
|
|
create extension if not exists pg_stat_statements; |
|
select * from pg_stat_statements where calls > 10 order by mean_time desc limit 20; |
|
|
|
show wal_level; |
|
|
|
select case when pg_is_in_recovery() then 'secondary' else 'primary' end as host_status; |
|
|
|
select case when (g.idx % 2 = 0) then null else lpad(g.idx::text, 20, '0') end |
|
from generate_series(1, 100) as g (idx); |
|
|
|
set search_path to public; |
|
|
|
--show temp_file_limit; |
|
--set temp_file_limit = '1 MB'; |
|
--set temp_file_limit = '10 MB'; |
|
--set temp_file_limit = '100 MB'; |
|
--show maintenance_work_mem; |
|
--set maintenance_work_mem = '1 MB'; |
|
--set maintenance_work_mem = '1 GB'; |
|
|
|
drop index concurrently if exists idx_ref_without_nulls; |
|
create index concurrently if not exists idx_ref_without_nulls on test (ref) where ref is not null; |
|
|
|
explain (analyze, buffers) select * from employee e; |
|
|
|
show shared_buffers; |
|
show max_wal_size; |
|
show work_mem; |
|
|
|
show maintenance_work_mem; |
|
show autovacuum_work_mem; |
|
show autovacuum_max_workers; |
|
-- set maintenance_work_mem = '256MB'; |
|
|
|
show temp_file_limit; |
|
|
|
show log_min_duration_statement; |
|
show log_destination; |
|
show logging_collector; |
|
show log_directory; |
|
show log_filename; |
|
show log_file_mode; |
|
show log_rotation_age; |
|
show log_rotation_size; |
|
show log_statement; |
|
show log_temp_files; |
|
|
|
create table if not exists test |
|
( |
|
id bigserial primary key, |
|
fld varchar(255), |
|
mark varchar(255), |
|
nil varchar(255) |
|
); |
|
|
|
insert into test |
|
select data.id, case when data.id % 2 = 0 then now()::text else null end, case when data.id % 2 = 0 then 'test_string'::text else null end, null |
|
from generate_series(1, 100000) as data(id); |
|
|
|
create index if not exists i_test_fld_with_nulls on test (fld); |
|
create index if not exists i_test_fld_without_nulls on test (fld) where fld is not null; |
|
create index if not exists i_test_mark_with_nulls on test (mark); |
|
create index if not exists i_test_mark_without_nulls on test (mark) where mark is not null; |
|
create index if not exists i_test_nil_with_nulls on test (nil); |
|
create index if not exists i_test_nil_without_nulls on test (nil) where nil is not null; |
|
--========================================================================================== |
|
--liquibase formatted sql |
|
--changeset gary.stafford:elections-sql splitStatements:false dbms:postgresql |
|
|
|
------------------------------------------------------ |
|
-- vote_totals view |
|
------------------------------------------------------ |
|
-- View a total of votes, by election, by candidate |
|
CREATE OR REPLACE VIEW vote_totals AS |
|
SELECT |
|
ROW_NUMBER() |
|
OVER ( |
|
ORDER BY cbe.election ) AS id, |
|
cbe.election, |
|
CONCAT(cbe.last_name, ', ', cbe.first_name) AS "candidate", |
|
COUNT(cbe.last_name) AS votes |
|
FROM vote, candidates_by_elections cbe |
|
WHERE (vote.election_candidate_id = cbe.id) |
|
GROUP BY cbe.election, cbe.last_name, cbe.first_name |
|
ORDER BY cbe.election, cbe.last_name, cbe.first_name; |
|
|
|
------------------------------------------------------ |
|
-- generate_random_votes function |
|
------------------------------------------------------ |
|
-- generate a random number of votes for all election candidates |
|
CREATE OR REPLACE FUNCTION generate_random_votes(n INTEGER DEFAULT 100) |
|
RETURNS VOID |
|
LANGUAGE plpgsql |
|
AS $$ |
|
BEGIN |
|
FOR counter IN 1..n LOOP |
|
INSERT INTO vote (election_candidate_id) VALUES ( |
|
(SELECT id |
|
FROM election_candidate |
|
OFFSET floor(random() * ( |
|
SELECT COUNT(*) |
|
FROM election_candidate)) |
|
LIMIT 1) |
|
); |
|
END LOOP; |
|
END; |
|
$$; |
|
|
|
------------------------------------------------------ |
|
-- generate_votes function |
|
------------------------------------------------------ |
|
-- generate a random number of votes within a range, for a specific election candidate |
|
CREATE OR REPLACE FUNCTION generate_votes(minVotes INTEGER DEFAULT 100, |
|
maxVotes INTEGER DEFAULT 500, |
|
electionTitle VARCHAR(100) DEFAULT 'NULL', |
|
lastNameCandidate VARCHAR(50) DEFAULT 'NULL') |
|
RETURNS VOID |
|
LANGUAGE plpgsql |
|
AS $$ |
|
BEGIN |
|
FOR counter IN 1..(Cast(RANDOM() * (maxVotes - minVotes) + minVotes AS INT)) LOOP |
|
INSERT INTO vote (election_candidate_id) |
|
VALUES ((SELECT Id |
|
FROM candidates_by_elections |
|
WHERE (election LIKE electionTitle) AND (last_name LIKE lastNameCandidate) |
|
)); |
|
END LOOP; |
|
END; |
|
$$; |
|
--========================================================================================== |
|
SELECT e.department_id, |
|
ROW_NUMBER() OVER (ORDER BY e.department_id ) AS id from employee e; |
|
|
|
SELECT * |
|
FROM employee |
|
OFFSET floor(random() * ( |
|
SELECT COUNT(*) |
|
FROM employee)) |
|
LIMIT 1 |
|
|
|
CREATE TABLE IF NOT EXISTS migrations ( |
|
id integer PRIMARY KEY, |
|
name varchar(100) UNIQUE NOT NULL, |
|
hash varchar(40) NOT NULL, -- sha1 hex encoded hash of the file name and contents, to ensure it hasn't been altered since applying the migration |
|
executed_at timestamp DEFAULT current_timestamp |
|
); |
|
|
|
SET statement_timeout = 0; |
|
SET lock_timeout = 0; |
|
SET idle_in_transaction_session_timeout = 0; |
|
SET client_encoding = 'UTF8'; |
|
SET standard_conforming_strings = on; |
|
SELECT pg_catalog.set_config('search_path', '', false); |
|
SET check_function_bodies = false; |
|
SET xmloption = content; |
|
SET client_min_messages = warning; |
|
SET row_security = off; |
|
SET default_tablespace = ''; |
|
SET default_table_access_method = heap; |
|
|
|
CREATE UNIQUE INDEX states_state_idx ON public.states USING btree (state); |
|
|
|
CREATE SEQUENCE public.serial_pk_pk_seq |
|
AS integer |
|
START WITH 1 |
|
INCREMENT BY 1 |
|
NO MINVALUE |
|
NO MAXVALUE |
|
CACHE 1; |
|
ALTER SEQUENCE public.serial_pk_pk_seq OWNED BY public.serial_pk.pk; |
|
ALTER TABLE ONLY public.serial_pk ALTER COLUMN pk SET DEFAULT nextval('public.serial_pk_pk_seq'::regclass); |
|
SELECT pg_catalog.setval('public.serial_pk_pk_seq', 2, true); |
|
--========================================================================================== |
|
SELECT 1 as result |
|
FROM employee e |
|
HAVING MIN(e.id) < MAX(e.id); |
|
|
|
|
|
SELECT COUNT(e.id) as count |
|
FROM employee e |
|
HAVING COUNT(e.id) < 100; |
|
|
|
SELECT max(e.id) as count |
|
FROM employee e |
|
WHERE e.id < 100; |
|
--========================================================================================== |
|
create procedure test(in nbr integer) |
|
language sql |
|
deterministic |
|
create local temporary table workingtree |
|
(like test2) |
|
on commit delete rows |
|
begin atomic |
|
declare prior_size integer; |
|
declare curr_size integer; |
|
|
|
Delete from workingtree; |
|
insert into workingtree select * from test2 where nbr = nbr; |
|
set curr_size = (select count(*) from workingtree); |
|
set prior_size = 0; |
|
|
|
while prior_size < curr_size |
|
do set prior_size = (select count(*) from test2); |
|
insert into workingtree select * from test2 where nbr in (select nbr from workingtree as w1 where w1.nbr not in (select w2.nbr from workingtree as w2)); |
|
set curr_size = (select count(*) from workingtree); |
|
end while; |
|
|
|
end; |
|
--========================================================================================== |
|
select name from table where name in (select name from table2 where table2.name = table.name); |
|
|
|
select id from table order by id desc limit 1; |
|
select top 1 id from table order by id desc; |
|
|
|
select name from analysis a join orders o on a.id = o.id |
|
where date between '2020-02-05 and '2020-02-05'::TIMESTAMP + INTERVAL '1 week'; |
|
|
|
create unlogged table name(); |
|
|
|
select pg_database_size(current_database()); |
|
|
|
while (select avg(price) from table) < 200 |
|
begin |
|
update table set price = price * 2; |
|
select max(price) from table if(select max(price) from table) > 500 |
|
break; |
|
end |
|
|
|
select * from table1 where a = x union all select * from table2 where b = y and a != x; |
|
|
|
select * from table1 t1 inner join table2 t2 on 1 = t2.id; |
|
|
|
alter table name auto_increment = 1; |
|
drop table name; crate table name(); |
|
|
|
select * from table where id % 2 = 0; |
|
select * from table where id % 2 != 0; |
|
|
|
select name from customers c join (select id from orders group by id having(orderid) > 2) o |
|
on c.id = o.id |
|
where c.city = 'test'; |
|
|
|
select value = any('{1, 2, 3}'::int[]); |
|
--========================================================================================== |
|
select code, |
|
lag(code) over(order by code) prev_code, |
|
lead(code) over(order by code) next_code, |
|
from table; |
|
|
|
select * from worker where worker_id <= (select count(workder_id) / 2 from worker); |
|
|
|
select id, name, row_number() over (order by id desc) from products; |
|
|
|
select dense_rank() over w as rank, |
|
name, department, salary |
|
from employees |
|
window w as (order by salary desc) |
|
order by rank, id; |
|
|
|
with salaries_cte as ( |
|
select salary, row_number() over (order by salary desc) as row_num from employees |
|
); |
|
select salary from salaries_cte where row_num = 5; |
|
|
|
select exists( |
|
select from pg_catalog.pg_class c join pg_catalog.pg_namespace n on n.oid = c.relnamespace |
|
where n.nspname = 'schema_name' |
|
and c.relname = 'table_name' |
|
and c.relkind = 'r' |
|
); |
|
--========================================================================================== |
|
select id, val from table1 t1 left join table2 t2 on t1.val = t2.val and t1.id > t2.id; |
|
|
|
select * from table where '{value}' = any(array); |
|
select * from table where array && '{value1, value2, value3}'; |
|
|
|
select name, score, dense_rank() over(order by score desc) as rank from table; |
|
|
|
select name, salary from employees order by salary desc limit 1 offset 2; |
|
select * from (select name, salary, dense_rank() over(order by salary desc) as rank from employees) subquery where rank = n; |
|
select name, salary from employees order by salary desc limit 1 offset (n - 1); |
|
|
|
cluster table1; |
|
alter table table1 set without cluster; |
|
CREATE TABLE test.cluster_table |
|
(id INTEGER, |
|
name VARCHAR) WITH (FILLFACTOR = 90); |
|
CREATE INDEX id_idx ON test.cluster_table (id); |
|
CLUSTER [VERBOSE] test.cluster_table USING id_idx; |
|
|
|
CREATE TABLE test.cluster_table |
|
(id INTEGER, |
|
name VARCHAR) WITH (FILLFACTOR = 90); |
|
CREATE INDEX id_idx ON test.cluster_table (id); |
|
INSERT INTO test.cluster_table |
|
SELECT (random( )*100)::INTEGER, |
|
'test' |
|
FROM generate_series(1,100) AS g(i); |
|
SELECT id |
|
FROM test.cluster_table; |
|
|
|
SELECT c.oid AS "OID", |
|
c.relname AS "Relation name" |
|
FROM pg_class c INNER JOIN pg_index i ON i.indrelid = c.oid |
|
WHERE c.relkind = 'r' AND |
|
c.relhasindex AND |
|
i.indisclustered; |
|
|
|
|
|
CREATE EXTENSION file_fdw; |
|
CREATE SERVER csv_log FOREIGN DATA WRAPPER file_fdw; |
|
CREATE FOREIGN TABLE test.csv ( |
|
id INTEGER, |
|
name VARCHAR |
|
) SERVER csv_log |
|
OPTIONS (filename '/var/lib/postgresql/file.csv', |
|
delimiter ';', format 'csv'); |
|
SELECT oid AS "OID", |
|
pg_relation_filepath(oid) AS "File path", |
|
pg_relation_size(oid) AS "Relation Size" |
|
FROM pg_class |
|
WHERE relname = 'csv'; |
|
|
|
CREATE EXTENSION postgres_fdw; |
|
DROP FOREIGN TABLE test.csv; |
|
CREATE SERVER pg_log FOREIGN DATA WRAPPER postgres_fdw |
|
OPTIONS (host '192.168.56.10', port '5432', dbname 'course_db'); |
|
CREATE USER MAPPING FOR test SERVER pg_log |
|
OPTIONS (user 'test', password 'test'); |
|
CREATE FOREIGN TABLE test.csv ( |
|
id INTEGER, |
|
name VARCHAR |
|
) SERVER pg_log |
|
OPTIONS (schema_name 'test', table_name 'user'); |
|
SELECT oid AS "OID", |
|
relname AS "Relation name", |
|
CASE |
|
WHEN relpersistence = 'p' THEN 'Permanent' |
|
WHEN relpersistence = 't' THEN 'Temporary' |
|
ELSE 'Unlogged' |
|
END AS "Type", |
|
relkind AS "Subtype" |
|
FROM pg_class |
|
WHERE relname = 'csv'; |
|
|
|
INSERT INTO test.hash (SELECT generate_series(0, 200000)); |
|
|
|
CREATE EXTENSION pg_repack; |
|
SELECT pg_repack('public.{table_name}'); |
|
--========================================================================================== |
|
select |
|
sum(case when allergies = 'Penicillin' and city = 'Burlington' then 1 else 0 end) as allergies_burl |
|
, sum(case when allergies = 'Penicillin' and city = 'Oakville' then 1 else 0 end) as allergies_oak |
|
|
|
select |
|
* |
|
FROM patients |
|
WHERE TRUE |
|
and 1 = (case when allergies = 'Penicillin' and city = 'Burlington' then 1 else 0 end) |
|
|
|
SELECT * |
|
FROM Customers |
|
WHERE EXISTS ( |
|
SELECT * |
|
FROM Orders |
|
WHERE Orders.CustomerID = Customers.CustomerID |
|
AND Orders.OrderDate > '2021-01-01' |
|
) |
|
--========================================================================================== |
|
copy(select * from table1) |
|
to 'table1.csv' |
|
with (FORMAT csv, header, delimiter ';'); |
|
|
|
copy kino |
|
from 'table1.csv' |
|
with (format csv, header, delimiter ';', encoding 'win1251') |
|
|
|
create extension mvcc_tuples; |
|
create extension pageinspect; |
|
|
|
select lower, upper, special, pagesize from page_header(get_raw_page('pg_class', 0)); |
|
--========================================================================================== |
|
select coalesce(sum(column1), 0) from table where column2 = 'test'; |
|
--========================================================================================== |
|
select timediff( |
|
(select update_time from information_schema.tables where table_schema='employees' and table_name='salaries'), |
|
(select create_time from information_schema.tables where table_schema='employees' and table_name='employees') |
|
) as data_load_time_diff; |
|
--========================================================================================== |
|
-- check for FKs where there is no matching index |
|
-- on the referencing side |
|
-- or a bad index |
|
|
|
WITH fk_actions ( code, action ) AS ( |
|
VALUES ( 'a', 'error' ), |
|
( 'r', 'restrict' ), |
|
( 'c', 'cascade' ), |
|
( 'n', 'set null' ), |
|
( 'd', 'set default' ) |
|
), |
|
fk_list AS ( |
|
SELECT pg_constraint.oid as fkoid, conrelid, confrelid as parentid, |
|
conname, relname, nspname, |
|
fk_actions_update.action as update_action, |
|
fk_actions_delete.action as delete_action, |
|
conkey as key_cols |
|
FROM pg_constraint |
|
JOIN pg_class ON conrelid = pg_class.oid |
|
JOIN pg_namespace ON pg_class.relnamespace = pg_namespace.oid |
|
JOIN fk_actions AS fk_actions_update ON confupdtype = fk_actions_update.code |
|
JOIN fk_actions AS fk_actions_delete ON confdeltype = fk_actions_delete.code |
|
WHERE contype = 'f' |
|
), |
|
fk_attributes AS ( |
|
SELECT fkoid, conrelid, attname, attnum |
|
FROM fk_list |
|
JOIN pg_attribute |
|
ON conrelid = attrelid |
|
AND attnum = ANY( key_cols ) |
|
ORDER BY fkoid, attnum |
|
), |
|
fk_cols_list AS ( |
|
SELECT fkoid, array_agg(attname) as cols_list |
|
FROM fk_attributes |
|
GROUP BY fkoid |
|
), |
|
index_list AS ( |
|
SELECT indexrelid as indexid, |
|
pg_class.relname as indexname, |
|
indrelid, |
|
indkey, |
|
indpred is not null as has_predicate, |
|
pg_get_indexdef(indexrelid) as indexdef |
|
FROM pg_index |
|
JOIN pg_class ON indexrelid = pg_class.oid |
|
WHERE indisvalid |
|
), |
|
fk_index_match AS ( |
|
SELECT fk_list.*, |
|
indexid, |
|
indexname, |
|
indkey::int[] as indexatts, |
|
has_predicate, |
|
indexdef, |
|
array_length(key_cols, 1) as fk_colcount, |
|
array_length(indkey,1) as index_colcount, |
|
round(pg_relation_size(conrelid)/(1024^2)::numeric) as table_mb, |
|
cols_list |
|
FROM fk_list |
|
JOIN fk_cols_list USING (fkoid) |
|
LEFT OUTER JOIN index_list |
|
ON conrelid = indrelid |
|
AND (indkey::int2[])[0:(array_length(key_cols,1) -1)] @> key_cols |
|
|
|
), |
|
fk_perfect_match AS ( |
|
SELECT fkoid |
|
FROM fk_index_match |
|
WHERE (index_colcount - 1) <= fk_colcount |
|
AND NOT has_predicate |
|
AND indexdef LIKE '%USING btree%' |
|
), |
|
fk_index_check AS ( |
|
SELECT 'no index' as issue, *, 1 as issue_sort |
|
FROM fk_index_match |
|
WHERE indexid IS NULL |
|
UNION ALL |
|
SELECT 'questionable index' as issue, *, 2 |
|
FROM fk_index_match |
|
WHERE indexid IS NOT NULL |
|
AND fkoid NOT IN ( |
|
SELECT fkoid |
|
FROM fk_perfect_match) |
|
), |
|
parent_table_stats AS ( |
|
SELECT fkoid, tabstats.relname as parent_name, |
|
(n_tup_ins + n_tup_upd + n_tup_del + n_tup_hot_upd) as parent_writes, |
|
round(pg_relation_size(parentid)/(1024^2)::numeric) as parent_mb |
|
FROM pg_stat_user_tables AS tabstats |
|
JOIN fk_list |
|
ON relid = parentid |
|
), |
|
fk_table_stats AS ( |
|
SELECT fkoid, |
|
(n_tup_ins + n_tup_upd + n_tup_del + n_tup_hot_upd) as writes, |
|
seq_scan as table_scans |
|
FROM pg_stat_user_tables AS tabstats |
|
JOIN fk_list |
|
ON relid = conrelid |
|
) |
|
SELECT nspname as schema_name, |
|
relname as table_name, |
|
conname as fk_name, |
|
issue, |
|
table_mb, |
|
writes, |
|
table_scans, |
|
parent_name, |
|
parent_mb, |
|
parent_writes, |
|
cols_list, |
|
indexdef |
|
FROM fk_index_check |
|
JOIN parent_table_stats USING (fkoid) |
|
JOIN fk_table_stats USING (fkoid) |
|
WHERE table_mb > 9 |
|
AND ( writes > 1000 |
|
OR parent_writes > 1000 |
|
OR parent_mb > 10 ) |
|
ORDER BY issue_sort, table_mb DESC, table_name, fk_name; |
|
--========================================================================================== |
|
select |
|
n.nspname as "Schema" |
|
,t.relname as "Table" |
|
,c.relname as "Index" |
|
from |
|
pg_catalog.pg_class c |
|
join pg_catalog.pg_namespace n on n.oid = c.relnamespace |
|
join pg_catalog.pg_index i on i.indexrelid = c.oid |
|
join pg_catalog.pg_class t on i.indrelid = t.oid |
|
where |
|
c.relkind = 'i' |
|
and n.nspname not in ('pg_catalog', 'pg_toast') |
|
--and pg_catalog.pg_table_is_visible(c.oid) |
|
order by |
|
n.nspname |
|
,t.relname |
|
,c.relname |
|
--========================================================================================== |
|
-- |
|
-- function: missing_fk_indexes |
|
-- purpose: List all foreing keys in the database without and index in the referencing table. |
|
-- author: Based on the work of Laurenz Albe |
|
-- see: https://www.cybertec-postgresql.com/en/index-your-foreign-key/ |
|
-- |
|
create or replace function missing_fk_indexes () |
|
returns table ( |
|
referencing_table regclass, |
|
fk_columns varchar, |
|
table_size varchar, |
|
fk_constraint name, |
|
referenced_table regclass |
|
) |
|
language sql as $$ |
|
select |
|
-- referencing table having ta foreign key declaration |
|
tc.conrelid::regclass as referencing_table, |
|
|
|
-- ordered list of foreign key columns |
|
string_agg(ta.attname, ', ' order by tx.n) as fk_columns, |
|
|
|
-- referencing table size |
|
pg_catalog.pg_size_pretty ( |
|
pg_catalog.pg_relation_size(tc.conrelid) |
|
) as table_size, |
|
|
|
-- name of the foreign key constraint |
|
tc.conname as fk_constraint, |
|
|
|
-- name of the target or destination table |
|
tc.confrelid::regclass as referenced_table |
|
|
|
from pg_catalog.pg_constraint tc |
|
|
|
-- enumerated key column numbers per foreign key |
|
cross join lateral unnest(tc.conkey) with ordinality as tx(attnum, n) |
|
|
|
-- name for each key column |
|
join pg_catalog.pg_attribute ta on ta.attnum = tx.attnum and ta.attrelid = tc.conrelid |
|
|
|
where not exists ( |
|
-- is there ta matching index for the constraint? |
|
select 1 from pg_catalog.pg_index i |
|
where |
|
i.indrelid = tc.conrelid and |
|
-- the first index columns must be the same as the key columns, but order doesn't matter |
|
(i.indkey::smallint[])[0:cardinality(tc.conkey)-1] @> tc.conkey) and |
|
tc.contype = 'f' |
|
group by |
|
tc.conrelid, |
|
tc.conname, |
|
tc.confrelid |
|
order by |
|
pg_catalog.pg_relation_size(tc.conrelid) desc |
|
$$; |
|
--========================================================================================== |
|
-- |
|
-- function: missing_fk_indexes2 |
|
-- purpose: List all foreing keys in the database without and index in the referencing table. |
|
-- The listing contains create index sentences |
|
-- author: Based on the work of Laurenz Albe |
|
-- see: https://www.cybertec-postgresql.com/en/index-your-foreign-key/ |
|
-- |
|
create or replace function missing_fk_indexes2 () |
|
returns setof varchar |
|
language sql as $$ |
|
select |
|
-- create index sentence |
|
'create index on ' || |
|
tc.conrelid::regclass || |
|
'(' || |
|
string_agg(ta.attname, ', ' order by tx.n) || |
|
')' as create_index |
|
|
|
from pg_catalog.pg_constraint tc |
|
|
|
-- enumerated key column numbers per foreign key |
|
cross join lateral unnest(tc.conkey) with ordinality as tx(attnum, n) |
|
|
|
-- name for each key column |
|
join pg_catalog.pg_attribute ta on ta.attnum = tx.attnum and ta.attrelid = tc.conrelid |
|
|
|
where not exists ( |
|
-- is there ta matching index for the constraint? |
|
select 1 from pg_catalog.pg_index i |
|
where |
|
i.indrelid = tc.conrelid and |
|
-- the first index columns must be the same as the key columns, but order doesn't matter |
|
(i.indkey::smallint[])[0:cardinality(tc.conkey)-1] @> tc.conkey) and |
|
tc.contype = 'f' |
|
group by |
|
tc.conrelid, |
|
tc.conname, |
|
tc.confrelid |
|
order by |
|
pg_catalog.pg_relation_size(tc.conrelid) desc |
|
$$; |
|
--========================================================================================== |
|
SELECT |
|
indexname, |
|
indexdef |
|
FROM |
|
pg_indexes |
|
WHERE |
|
tablename = 'table_name'; |
|
--========================================================================================== |
|
WITH test(x) AS ( |
|
VALUES (''), ('.'), ('.0'), ('0.'), ('0'), ('1'), ('123'), |
|
('123.456'), ('abc'), ('1..2'), ('1.2.3.4'), ('1x234'), ('1.234e-5')) |
|
|
|
SELECT x |
|
, x ~ '^([0-9]+[.]?[0-9]*|[.][0-9]+)$' AS isnumeric |
|
FROM test; |
|
--========================================================================================== |
|
CREATE OR REPLACE FUNCTION isnumeric(text) RETURNS BOOLEAN AS $$ |
|
DECLARE x NUMERIC; |
|
BEGIN |
|
x = $1::NUMERIC; |
|
RETURN TRUE; |
|
EXCEPTION WHEN others THEN |
|
RETURN FALSE; |
|
END; |
|
$$ |
|
STRICT |
|
LANGUAGE plpgsql IMMUTABLE; |
|
--========================================================================================== |
|
WITH test(x) AS ( VALUES (''), ('.'), ('.0'), ('0.'), ('0'), ('1'), ('123'), |
|
('123.456'), ('abc'), ('1..2'), ('1.2.3.4'), ('1x234'), ('1.234e-5')) |
|
SELECT x, isnumeric(x) FROM test; |
|
--========================================================================================== |
|
SELECT m.title, SUM(m.body::numeric) |
|
FROM messages as m |
|
WHERE jsonb_typeof(m.body) = 'number' |
|
GROUP BY m.title; |
|
--========================================================================================== |
|
create function isnumeric(text) returns boolean |
|
immutable |
|
language plpgsql |
|
as $$ |
|
begin |
|
if $1 is not null then |
|
return (select $1 ~ '^(([-+]?[0-9]+(\.[0-9]+)?)|([-+]?\.[0-9]+))$'); |
|
else |
|
return false; |
|
end if; |
|
end; |
|
$$ |
|
; |
|
--========================================================================================== |
|
SELECT id FROM mytable |
|
WHERE message ~ '[АаБбВвГгДдЕеЁёЖжЗзИиЙйКкЛлМмНнОоПпРрСсТтУуФфХхЦцЧчШшЩщЪъЫыЬьЭэЮюЯя]'; |
|
--========================================================================================== |
|
create table charfreq ( |
|
c text, |
|
f float, |
|
lang text |
|
); |
|
insert into charfreq values |
|
('а', 8.04, 'ru'), |
|
('б', 1.55, 'ru'), |
|
('в', 4.75, 'ru'), |
|
... |
|
('a', 8.167, 'en'), |
|
('b', 1.492, 'en'), |
|
('c', 2.782, 'en'), |
|
... |
|
('ï', 0.005, 'fr'), |
|
('ô', 0.023, 'fr'), |
|
('ù', 0.058, 'fr'), |
|
('û', 0.06 , 'fr'); |
|
|
|
insert into test values |
|
(1, 'hi'), |
|
(2, 'ok'), |
|
(3, 'துய'), |
|
(4, 'нет'), |
|
(5, 'été'); -- a French message, just for fun |
|
|
|
select id, message, lang, score |
|
from ( |
|
select *, row_number() OVER (partition by id, message order by score desc) as rownum |
|
from ( |
|
select id, message, lang, coalesce(sum(f), 0)/length(message) as score |
|
from ( |
|
select *, unnest(STRING_TO_ARRAY(message, NULL)) as c from test |
|
) as a |
|
left join charfreq b |
|
using (c) |
|
group by 1,2,3 |
|
) as a |
|
) as a |
|
where rownum = 1; |
|
--========================================================================================== |
|
CREATE TABLE MESSAGE ( |
|
Id INTEGER PRIMARY KEY, |
|
MESSAGE VARCHAR (50) |
|
); |
|
|
|
INSERT INTO MESSAGE VALUES (1, 'hi');//False |
|
INSERT INTO MESSAGE VALUES (2, 'ok');//False |
|
INSERT INTO MESSAGE VALUES (3, 'துய');//False |
|
INSERT INTO MESSAGE VALUES (4, 'нет');//True |
|
INSERT INTO MESSAGE VALUES (5, 'нет-_*/?/()=.,123 ');//True |
|
INSERT INTO MESSAGE VALUES (6, 'нет 123');//True |
|
INSERT INTO MESSAGE VALUES (6, 'нет 123AAAA');//False |
|
|
|
SELECT * FROM message m |
|
WHERE |
|
ARRAY(SELECT ASCII(unnest(STRING_TO_ARRAY(REGEXP_REPLACE(m.message, '[^[:alnum:]]+', '', 'g'), NULL)))) <@ |
|
ARRAY(SELECT ASCII(unnest(STRING_TO_ARRAY('АаБбВвГгДдЕеЁёЖжЗзИиЙйКкЛлМмНнОоПпРрСсТтУуФфХхЦцЧчШшЩщЪъЫыЬьЭэЮюЯя0123456789', NULL)))) |
|
--========================================================================================== |
|
SELECT ns.nspname AS schema |
|
, class.relname AS "table" |
|
, con.conname AS "constraint" |
|
, con.condeferrable AS "deferrable" |
|
, con.condeferred AS deferred |
|
FROM pg_constraint con |
|
INNER JOIN pg_class class ON class.oid = con.conrelid |
|
INNER JOIN pg_namespace ns ON ns.oid = class.relnamespace |
|
WHERE con.contype IN ('p', 'u') |
|
AND ns.nspname != 'pg_catalog' |
|
ORDER BY 1, 2, 3; |
|
--========================================================================================== |
|
CREATE TABLE `products` ( |
|
`product_id` bigint(20) NOT NULL, |
|
`product_name` varchar(100) NOT NULL, |
|
`price` decimal(16, 2) NOT NULL, |
|
`brand_id` int(11) NOT NULL, |
|
PRIMARY KEY (`product_id`), |
|
CONSTRAINT `fk_brand_id` FOREIGN KEY (`brand_id`) |
|
REFERENCES `brands` (`brand_id`) |
|
); |
|
--========================================================================================== |
|
CREATE TABLE `products` ( |
|
`product_id` bigint(20) NOT NULL, |
|
`product_name` varchar(100) NOT NULL, |
|
`price` decimal(16, 2) NOT NULL, |
|
`brand_id` int(11) NOT NULL, |
|
/* Note : `extra` column store extra information and is declared as JSON data type column. */ |
|
`extra` JSON NOT NULL, |
|
PRIMARY KEY (`product_id`), |
|
CONSTRAINT `fk_brand_id` FOREIGN KEY (`brand_id`) REFERENCES `brands` (`brand_id`) |
|
); |
|
|
|
SELECT product_id, product_name, price, extra |
|
FROM products |
|
WHERE extra -> '$.size' = 'L' |
|
LIMIT 5; |
|
--========================================================================================== |
|
SELECT |
|
product_id, product_name, price, category_code |
|
FROM products |
|
WHERE |
|
brand_id = (SELECT brand_id FROM brands WHERE brand_name = 'nike') |
|
ORDER BY price DESC |
|
LIMIT 10; |
|
--========================================================================================== |
|
-- It is a particularly resource-intensive analytical query. |
|
-- The events table generates an average of 1.8 million records per day. |
|
WITH top_merchandises AS ( |
|
SELECT |
|
product_id, |
|
COUNT(*) AS viewed |
|
FROM events |
|
WHERE event_type = 'view' |
|
AND event_time >= '2019-11-30 17:59:59' |
|
AND event_time <= '2019-11-30 23:59:59' |
|
GROUP BY product_id |
|
ORDER BY viewed DESC |
|
LIMIT 10 |
|
); |
|
|
|
SELECT |
|
products.product_id, |
|
products.product_name, |
|
top_merchandises.viewed |
|
FROM top_merchandises |
|
JOIN products ON top_merchandises.product_id = products.product_id |
|
ORDER BY viewed DESC |
|
--========================================================================================== |
|
-- It is a particularly resource-intensive analytical query. |
|
-- The events table generates an average of 1.8 million records per day. |
|
SELECT ( |
|
COUNT(CASE WHEN event_type = 'purchase' THEN 1 ELSE NULL END) / |
|
COUNT(CASE WHEN event_type = 'view' THEN 1 ELSE NULL END) |
|
) AS bought_rate |
|
FROM events |
|
WHERE event_time >= '2019-11-30 17:59:59' |
|
AND event_time <= '2019-11-30 23:59:59' |
|
--========================================================================================== |
|
-- It is a particularly resource-intensive analytical query. |
|
-- The events table generates an average of 1.8 million records per day. |
|
WITH top_sellers AS ( |
|
SELECT |
|
product_id, |
|
SUM(price) AS sold |
|
FROM events |
|
WHERE event_type = 'purchase' |
|
AND event_time >= '2019-11-30 11:59:59' |
|
AND event_time <= '2019-11-30 23:59:59' |
|
GROUP BY product_id |
|
ORDER BY sold DESC |
|
LIMIT 10 |
|
) |
|
SELECT |
|
products.product_id, |
|
products.product_name, |
|
top_sellers.sold |
|
FROM top_sellers |
|
JOIN products ON top_sellers.product_id = products.product_id |
|
ORDER BY sold DESC |
|
--========================================================================================== |
|
-- SET search_path TO TPCC; |
|
-- Condition 1: W_YTD = sum(D_YTD) |
|
SELECT * FROM (SELECT w.w_id, w.w_ytd, d.sum_d_ytd |
|
FROM bmsql_warehouse w, |
|
(SELECT d_w_id, SUM(d_ytd) sum_d_ytd |
|
FROM bmsql_district |
|
GROUP BY d_w_id) d |
|
WHERE w.w_id = d.d_w_id) as x |
|
WHERE w_ytd != sum_d_ytd; |
|
|
|
-- Condition 2: D_NEXT_O_ID - 1 = max(O_ID) = max(NO_O_ID) |
|
SELECT * FROM (SELECT d.d_w_id, d.d_id, d.d_next_o_id, o.max_o_id, no.max_no_o_id |
|
FROM bmsql_district d, |
|
(SELECT o_w_id, o_d_id, MAX(o_id) max_o_id |
|
FROM bmsql_oorder |
|
GROUP BY o_w_id, o_d_id) o, |
|
(SELECT no_w_id, no_d_id, MAX(no_o_id) max_no_o_id |
|
FROM bmsql_new_order |
|
GROUP BY no_w_id, no_d_id) no |
|
WHERE d.d_w_id = o.o_w_id AND d.d_w_id = no.no_w_id AND |
|
d.d_id = o.o_d_id AND d.d_id = no.no_d_id) as x |
|
WHERE d_next_o_id - 1 != max_o_id OR d_next_o_id - 1 != max_no_o_id; |
|
|
|
-- Condition 3: max(NO_O_ID) - min(NO_O_ID) + 1 |
|
-- = [number of rows in the NEW-ORDER table for this bmsql_district] |
|
SELECT * FROM (SELECT no_w_id, no_d_id, MAX(no_o_id) max_no_o_id, |
|
MIN(no_o_id) min_no_o_id, COUNT(*) count_no |
|
FROM bmsql_new_order |
|
GROUP BY no_w_id, no_d_Id) as x |
|
WHERE max_no_o_id - min_no_o_id + 1 != count_no; |
|
|
|
-- Condition 4: sum(O_OL_CNT) |
|
-- = [number of rows in the ORDER-LINE table for this bmsql_district] |
|
SELECT * FROM (SELECT o.o_w_id, o.o_d_id, o.sum_o_ol_cnt, ol.count_ol |
|
FROM (SELECT o_w_id, o_d_id, SUM(o_ol_cnt) sum_o_ol_cnt |
|
FROM bmsql_oorder |
|
GROUP BY o_w_id, o_d_id) o, |
|
(SELECT ol_w_id, ol_d_id, COUNT(*) count_ol |
|
FROM bmsql_order_line |
|
GROUP BY ol_w_id, ol_d_id) ol |
|
WHERE o.o_w_id = ol.ol_w_id AND |
|
o.o_d_id = ol.ol_d_id) as x |
|
WHERE sum_o_ol_cnt != count_ol; |
|
|
|
-- Condition 5: For any row in the ORDER table, O_CARRIER_ID is set to a null |
|
-- value if and only if there is a corresponding row in the |
|
-- NEW-ORDER table |
|
SELECT * FROM (SELECT o.o_w_id, o.o_d_id, o.o_id, o.o_carrier_id, no.count_no |
|
FROM bmsql_oorder o, |
|
(SELECT no_w_id, no_d_id, no_o_id, COUNT(*) count_no |
|
FROM bmsql_new_order |
|
GROUP BY no_w_id, no_d_id, no_o_id) no |
|
WHERE o.o_w_id = no.no_w_id AND |
|
o.o_d_id = no.no_d_id AND |
|
o.o_id = no.no_o_id) as x |
|
WHERE (o_carrier_id IS NULL AND count_no = 0) OR |
|
(o_carrier_id IS NOT NULL AND count_no != 0); |
|
|
|
-- Condition 6: For any row in the ORDER table, O_OL_CNT must equal the number |
|
-- of rows in the ORDER-LINE table for the corresponding order |
|
SELECT * FROM (SELECT o.o_w_id, o.o_d_id, o.o_id, o.o_ol_cnt, ol.count_ol |
|
FROM bmsql_oorder o, |
|
(SELECT ol_w_id, ol_d_id, ol_o_id, COUNT(*) count_ol |
|
FROM bmsql_order_line |
|
GROUP BY ol_w_id, ol_d_id, ol_o_id) ol |
|
WHERE o.o_w_id = ol.ol_w_id AND |
|
o.o_d_id = ol.ol_d_id AND |
|
o.o_id = ol.ol_o_id) as x |
|
WHERE o_ol_cnt != count_ol; |
|
|
|
-- Condition 7: For any row in the ORDER-LINE table, OL_DELIVERY_D is set to |
|
-- a null date/time if and only if the corresponding row in the |
|
-- ORDER table has O_CARRIER_ID set to a null value |
|
SELECT * FROM (SELECT ol.ol_w_id, ol.ol_d_id, ol.ol_o_id, ol.ol_delivery_d, |
|
o.o_carrier_id |
|
FROM bmsql_order_line ol, |
|
bmsql_oorder o |
|
WHERE ol.ol_w_id = o.o_w_id AND |
|
ol.ol_d_id = o.o_d_id AND |
|
ol.ol_o_id = o.o_id) as x |
|
WHERE (ol_delivery_d IS NULL AND o_carrier_id IS NOT NULL) OR |
|
(ol_delivery_d IS NOT NULL AND o_carrier_id IS NULL); |
|
|
|
-- Condition 8: W_YTD = sum(H_AMOUNT) |
|
SELECT * |
|
FROM (SELECT w.w_id, w.w_ytd, h.sum_h_amount |
|
FROM bmsql_warehouse w, |
|
(SELECT h_w_id, SUM(h_amount) sum_h_amount FROM bmsql_history GROUP BY h_w_id) h |
|
WHERE w.w_id = h.h_w_id) as x |
|
WHERE w_ytd != sum_h_amount; |
|
|
|
-- Condition 9: D_YTD = sum(H_AMOUNT) |
|
SELECT * |
|
FROM (SELECT d.d_w_id, d.d_id, d.d_ytd, h.sum_h_amount |
|
FROM bmsql_district d, |
|
(SELECT h_w_id, h_d_id, SUM(h_amount) sum_h_amount |
|
FROM bmsql_history |
|
GROUP BY h_w_id, h_d_id) h |
|
WHERE d.d_w_id = h.h_w_id |
|
AND d.d_id = h.h_d_id) as x |
|
WHERE d_ytd != sum_h_amount; |
|
--========================================================================================== |
|
-- ---- |
|
-- Extra Schema objects/definitions for history.hist_id in PostgreSQL |
|
-- ---- |
|
|
|
-- ---- |
|
-- This is an extra column not present in the TPC-C |
|
-- specs. It is useful for replication systems like |
|
-- Bucardo and Slony-I, which like to have a primary |
|
-- key on a table. It is an auto-increment or serial |
|
-- column type. The definition below is compatible |
|
-- with Oracle 11g, using a sequence and a trigger. |
|
-- ---- |
|
-- Adjust the sequence above the current max(hist_id) |
|
select setval('bmsql_hist_id_seq', (select max(hist_id) from bmsql_history)); |
|
|
|
-- Make nextval(seq) the default value of the hist_id column. |
|
alter table bmsql_history |
|
alter column hist_id set default nextval('bmsql_hist_id_seq'); |
|
|
|
-- Add a primary key history(hist_id) |
|
alter table bmsql_history add primary key (hist_id); |
|
--========================================================================================== |
|
copy bmsql_config |
|
(cfg_name, cfg_value) |
|
from '/tmp/csv/bmsql_config.csv' WITH CSV; |
|
|
|
copy bmsql_warehouse |
|
(w_id, w_ytd, w_tax, w_name, w_street_1, w_street_2, w_city, w_state, w_zip) |
|
from '/tmp/csv/bmsql_warehouse.csv' WITH CSV; |
|
|
|
copy bmsql_item |
|
(i_id, i_name, i_price, i_data, i_im_id) |
|
from '/tmp/csv/bmsql_item.csv' WITH CSV; |
|
|
|
copy bmsql_stock |
|
(s_i_id, s_w_id, s_quantity, s_ytd, s_order_cnt, s_remote_cnt, s_data, |
|
s_dist_01, s_dist_02, s_dist_03, s_dist_04, s_dist_05, |
|
s_dist_06, s_dist_07, s_dist_08, s_dist_09, s_dist_10) |
|
from '/tmp/csv/bmsql_stock.csv' WITH CSV; |
|
|
|
copy bmsql_district |
|
(d_id, d_w_id, d_ytd, d_tax, d_next_o_id, d_name, d_street_1, |
|
d_street_2, d_city, d_state, d_zip) |
|
from '/tmp/csv/bmsql_district.csv' WITH CSV; |
|
|
|
copy bmsql_customer |
|
(c_id, c_d_id, c_w_id, c_discount, c_credit, c_last, c_first, c_credit_lim, |
|
c_balance, c_ytd_payment, c_payment_cnt, c_delivery_cnt, c_street_1, |
|
c_street_2, c_city, c_state, c_zip, c_phone, c_since, c_middle, c_data) |
|
from '/tmp/csv/bmsql_customer.csv' WITH CSV; |
|
|
|
copy bmsql_history |
|
(hist_id, h_c_id, h_c_d_id, h_c_w_id, h_d_id, h_w_id, h_date, h_amount, h_data) |
|
from '/tmp/csv/bmsql_history.csv' WITH CSV; |
|
|
|
copy bmsql_oorder |
|
(o_id, o_w_id, o_d_id, o_c_id, o_carrier_id, o_ol_cnt, o_all_local, o_entry_d) |
|
from '/tmp/csv/bmsql_oorder.csv' WITH CSV NULL AS 'NULL'; |
|
|
|
copy bmsql_order_line |
|
(ol_w_id, ol_d_id, ol_o_id, ol_number, ol_i_id, ol_delivery_d, |
|
ol_amount, ol_supply_w_id, ol_quantity, ol_dist_info) |
|
from '/tmp/csv/bmsql_order_line.csv' WITH CSV NULL AS 'NULL'; |
|
|
|
copy bmsql_new_order |
|
(no_w_id, no_d_id, no_o_id) |
|
from '/tmp/csv/bmsql_new_order.csv' WITH CSV; |
|
--========================================================================================== |
|
# Can be used with |
|
# mysql < check-placement.sql | grep -v us-east-1 |
|
# -or- |
|
# mysql < check-placement.sql | grep us-east-1 |
|
|
|
use information_schema; |
|
WITH store_index AS (SELECT store_id, substring(address, -1) as node_number, label->>"$[0].value" as aws_region from tikv_store_status) |
|
SELECT |
|
node_number as node, aws_region, is_leader, count(*) as c |
|
FROM tikv_region_peers |
|
INNER JOIN TIKV_REGION_STATUS USING (region_id) |
|
INNER JOIN store_index USING (store_id) |
|
WHERE db_name = 'test' |
|
GROUP BY |
|
node_number, is_leader |
|
ORDER BY node_number; |
|
--========================================================================================== |
|
update users, prospect_users |
|
set users.about = prospect_users.about |
|
where prospect_users.username = users.username; |
|
========================================================================================== |
|
delete users |
|
from users, prospect_users |
|
where users.username = prospect_users.username |
|
and NOT prospect_users.active |
|
--========================================================================================== |
|
SELECT users.*, posts.* |
|
FROM users |
|
LEFT JOIN posts |
|
ON posts.user_id = users.id |
|
WHERE posts.title LIKE '%SQL%'; |
|
--========================================================================================== |
|
SELECT users.*, posts.* |
|
FROM users |
|
LEFT JOIN posts |
|
ON posts.user_id = users.id |
|
AND posts.title LIKE '%SQL%'; |
|
--========================================================================================== |
|
SELECT users.*, posts.* |
|
FROM posts |
|
LEFT JOIN users |
|
ON posts.user_id = users.id; |
|
========================================================================================== |
|
SELECT users.*, posts.* |
|
FROM users |
|
RIGHT JOIN posts |
|
ON posts.user_id = users.id; |
|
--========================================================================================== |
|
UPDATE CUSTOMERS |
|
SET SALARY = SALARY * 0.25 |
|
WHERE AGE IN ( |
|
SELECT AGE |
|
FROM CUSTOMERS_BKP |
|
WHERE AGE >= 27 |
|
); |
|
--========================================================================================== |
|
DELETE FROM CUSTOMERS |
|
WHERE AGE IN ( |
|
SELECT AGE |
|
FROM CUSTOMERS_BKP |
|
WHERE AGE >= 27 |
|
); |
|
========================================================================================== |
|
SELECT id, name, amount, date |
|
FROM customer |
|
LEFT JOIN orders |
|
ON customers.id = orders.customer_id |
|
UNION |
|
SELECT id, name, amount, date |
|
FROM customer |
|
RIGHT JOIN orders |
|
ON customers.id = orders.customer_id |
|
--========================================================================================== |
|
SELECT customer_name, SUM(price) AS Total_Purchase |
|
FROM purchase |
|
WHERE customer_name |
|
LIKE "S%" |
|
GROUP BY customer_name |
|
HAVING SUM(price) > 1000; |
|
--========================================================================================== |
|
SELECT customer_name, AVG(price) AS Average_Purchase |
|
FROM purchase |
|
GROUP BY customer_name |
|
HAVING AVG(price) > 550 |
|
ORDER BY customer_name DESC; |
|
--========================================================================================== |
|
SELECT |
|
mz_catalog.mz_sources.name AS source_name, |
|
source_id AS source_id, |
|
count(*) AS error_count |
|
FROM mz_internal.mz_source_status_history h |
|
JOIN mz_catalog.mz_sources ON h.source_id = mz_catalog.mz_sources.id |
|
WHERE h.error IS NOT NULL |
|
GROUP BY 1, 2; |
|
--========================================================================================== |
|
select Description from Table_Name group by Description having max(len(Description)) > 27; |
|
select tt.name, max(tt.length) from (select t.name, sum(len(t.content)) from table t group by 1) as tt; |
|
SELECT TOP 1 column_name, LEN(column_name) AS Lenght FROM table_name ORDER BY LEN(column_name) DESC |
|
select ID, [description], len([description]) as descriptionlength |
|
FROM [database1].[dbo].[table1] |
|
where len([description]) = |
|
(select max(len([description])) |
|
FROM [database1].[dbo].[table1] |
|
--========================================================================================== |
|
CREATE POLICY post_owner_policy ON post |
|
USING (owner = current_user); |
|
|
|
CREATE POLICY post_read_policy ON post FOR SELECT |
|
USING (published = true); |
|
--========================================================================================== |
|
CREATE FUNCTION add_them(a integer, b integer) |
|
RETURNS integer AS $$ |
|
SELECT a + b; |
|
$$ LANGUAGE SQL IMMUTABLE; |
|
--========================================================================================== |
|
CREATE TABLE COMPANY7( |
|
ID INT PRIMARY KEY NOT NULL, |
|
NAME TEXT, |
|
AGE INT , |
|
ADDRESS CHAR(50), |
|
SALARY REAL, |
|
EXCLUDE USING gist |
|
(NAME WITH =, |
|
AGE WITH <>) |
|
); |
|
|
|
INSERT INTO COMPANY7 VALUES(1, 'Paul', 32, 'California', 20000.00 ); |
|
INSERT INTO COMPANY7 VALUES(2, 'Paul', 32, 'Texas', 20000.00 ); |
|
INSERT INTO COMPANY7 VALUES(3, 'Paul', 42, 'California', 20000.00 ); |
|
--========================================================================================== |
|
CREATE TABLE COMPANY5( |
|
ID INT PRIMARY KEY NOT NULL, |
|
NAME TEXT NOT NULL, |
|
AGE INT NOT NULL, |
|
ADDRESS CHAR(50), |
|
SALARY REAL CHECK(SALARY > 0) |
|
); |
|
--========================================================================================== |
|
create schema rabbitmq; |
|
|
|
create or replace function rabbitmq.send_message(channel text, routing_key text, message text) returns void as $$ |
|
select pg_notify(channel, routing_key || '|' || message); |
|
$$ stable language sql; |
|
|
|
create or replace function rabbitmq.on_row_change() returns trigger as $$ |
|
declare |
|
routing_key text; |
|
row record; |
|
begin |
|
routing_key := 'row_change' |
|
'.table-'::text || TG_TABLE_NAME::text || |
|
'.event-'::text || TG_OP::text; |
|
if (TG_OP = 'DELETE') then |
|
row := old; |
|
elsif (TG_OP = 'UPDATE') then |
|
row := new; |
|
elsif (TG_OP = 'INSERT') then |
|
row := new; |
|
end if; |
|
-- change 'events' to the desired channel/exchange name |
|
perform rabbitmq.send_message('events', routing_key, row_to_json(row)::text); |
|
return null; |
|
end; |
|
$$ stable language plpgsql; |
|
--========================================================================================== |
|
SELECT |
|
CONCAT(e1.FirstName, ' ', e1.LastName) AS Employee, |
|
CONCAT(e2.FirstName, ' ', e2.LastName) AS Manager |
|
FROM Employees e1 |
|
LEFT JOIN Employees e2 |
|
ON e1.ReportsTo = e2.EmployeeId; |
|
--========================================================================================== |
|
-- models/customer_revenue_incremental.sql |
|
{{ config(materialized='incremental', unique_key='customer_id') }} |
|
|
|
WITH latest_orders AS ( |
|
SELECT * FROM orders WHERE updated_at > (SELECT MAX(updated_at) FROM {{ this }}) |
|
), |
|
updated_totals AS ( |
|
SELECT customer_id, SUM(order_total) AS total_sales FROM latest_orders GROUP BY customer_id |
|
), |
|
existing_totals AS ( |
|
SELECT customer_id, total_sales FROM {{ this }} WHERE customer_id NOT IN (SELECT customer_id FROM updated_totals) |
|
) |
|
SELECT * FROM updated_totals |
|
UNION ALL |
|
SELECT * FROM existing_totals; |
|
|
|
-- models/customer_revenue.sql |
|
{{ config(materialized='view', indexes=[{'columns': ['customer_id']}]) }} |
|
|
|
SELECT |
|
customer_id, |
|
SUM(order_total) AS total_sales |
|
FROM orders |
|
GROUP BY customer_id; |
|
--========================================================================================== |
|
CREATE VIEW dynamic_pricing AS |
|
WITH |
|
recent_prices AS ( |
|
SELECT |
|
grp.product_id, |
|
avg(sub.price) AS avg_price |
|
FROM (SELECT DISTINCT product_id FROM public.sales) AS grp, |
|
LATERAL ( |
|
SELECT |
|
sales.product_id, |
|
sales.price |
|
FROM public.sales |
|
WHERE sales.product_id = grp.product_id |
|
ORDER BY sales.sale_date DESC LIMIT 10 |
|
) AS sub |
|
GROUP BY grp.product_id |
|
), |
|
|
|
promotion_effect AS ( |
|
SELECT |
|
p.product_id, |
|
min(pr.promotion_discount) AS promotion_discount |
|
FROM public.promotions AS pr |
|
INNER JOIN public.products AS p ON pr.product_id = p.product_id |
|
WHERE pr.active = TRUE |
|
GROUP BY p.product_id |
|
), |
|
|
|
popularity_score AS ( |
|
SELECT |
|
s.product_id, |
|
rank() OVER (PARTITION BY p.category_id ORDER BY count(s.sale_id) DESC) AS popularity_rank, |
|
count(s.sale_id) AS sale_count |
|
FROM public.sales AS s |
|
INNER JOIN public.products AS p ON s.product_id = p.product_id |
|
GROUP BY s.product_id, p.category_id |
|
), |
|
|
|
inventory_status AS ( |
|
SELECT |
|
i.product_id, |
|
sum(i.stock) AS total_stock, |
|
rank() OVER (ORDER BY sum(i.stock) DESC) AS stock_rank |
|
FROM public.inventory AS i |
|
GROUP BY i.product_id |
|
), |
|
|
|
high_demand_products AS ( |
|
SELECT |
|
p.product_id, |
|
avg(s.sale_price) AS avg_sale_price, |
|
count(s.sale_id) AS total_sales |
|
FROM public.products AS p |
|
INNER JOIN public.sales AS s ON p.product_id = s.product_id |
|
GROUP BY p.product_id |
|
HAVING count(s.sale_id) > (SELECT avg(total_sales) FROM (SELECT count(*) AS total_sales FROM public.sales GROUP BY product_id) AS subquery) |
|
), |
|
|
|
dynamic_pricing AS ( |
|
SELECT |
|
p.product_id, |
|
p.base_price, |
|
CASE |
|
WHEN pop.popularity_rank <= 3 THEN 1.2 |
|
WHEN pop.popularity_rank BETWEEN 4 AND 10 THEN 1.1 |
|
ELSE 0.9 |
|
END AS popularity_adjustment, |
|
rp.avg_price, |
|
coalesce(1.0 - (pe.promotion_discount / 100), 1) AS promotion_discount, |
|
CASE |
|
WHEN inv.stock_rank <= 3 THEN 1.1 |
|
WHEN inv.stock_rank BETWEEN 4 AND 10 THEN 1.05 |
|
ELSE 1 |
|
END AS stock_adjustment, |
|
CASE |
|
WHEN p.base_price > rp.avg_price THEN 1 + (p.base_price - rp.avg_price) / rp.avg_price |
|
ELSE 1 - (rp.avg_price - p.base_price) / rp.avg_price |
|
END AS demand_multiplier, |
|
hd.avg_sale_price, |
|
CASE |
|
WHEN p.product_name ILIKE '%cheap%' THEN 0.8 |
|
ELSE 1.0 |
|
END AS additional_discount |
|
FROM public.products AS p |
|
LEFT JOIN recent_prices AS rp ON p.product_id = rp.product_id |
|
LEFT JOIN promotion_effect AS pe ON p.product_id = pe.product_id |
|
INNER JOIN popularity_score AS pop ON p.product_id = pop.product_id |
|
LEFT JOIN inventory_status AS inv ON p.product_id = inv.product_id |
|
LEFT JOIN high_demand_products AS hd ON p.product_id = hd.product_id |
|
) |
|
|
|
SELECT |
|
dp.product_id, |
|
round(dp.base_price * dp.popularity_adjustment * dp.stock_adjustment * dp.demand_multiplier, 2) AS adjusted_price, |
|
round(dp.base_price * dp.popularity_adjustment * dp.stock_adjustment * dp.demand_multiplier * dp.promotion_discount * dp.additional_discount, 2) AS discounted_price |
|
FROM dynamic_pricing AS dp; |
|
|
|
|
|
|
|
ALTER TABLE public.inventory ADD CONSTRAINT inventory_product_id_fkey FOREIGN KEY (product_id) REFERENCES public.products (product_id); |
|
ALTER TABLE public.promotions ADD CONSTRAINT promotions_product_id_fkey FOREIGN KEY (product_id) REFERENCES public.products (product_id); |
|
ALTER TABLE public.sales ADD CONSTRAINT sales_product_id_fkey FOREIGN KEY (product_id) REFERENCES public.products (product_id); |
|
|
|
CREATE INDEX idx_products_product_name ON products (product_name); |
|
CREATE INDEX idx_sales_product_id ON sales (product_id); |
|
CREATE INDEX idx_sales_sale_date ON sales (sale_date); |
|
CREATE INDEX idx_sales_product_id_sale_date ON sales (product_id, sale_date); |
|
CREATE INDEX idx_promotions_product_id ON promotions (product_id); |
|
CREATE INDEX idx_promotions_active ON promotions (active); |
|
CREATE INDEX idx_promotions_product_id_active ON promotions (product_id, active); |
|
CREATE INDEX idx_inventory_product_id ON inventory (product_id); |
|
--========================================================================================== |
|
SELECT c.oid::regclass as table_name, |
|
greatest(age(c.relfrozenxid),age(t.relfrozenxid)) as age |
|
FROM pg_class c |
|
LEFT JOIN pg_class t ON c.reltoastrelid = t.oid |
|
WHERE c.relkind IN ('r', 'm'); |
|
--========================================================================================== |
|
-- Шаг 1: Убираем значение по умолчанию для колонки id |
|
ALTER TABLE ci_stages ALTER COLUMN id DROP DEFAULT; |
|
|
|
-- Шаг 2: Удаляем внешний ключ из таблицы p_ci_builds |
|
ALTER TABLE p_ci_builds DROP CONSTRAINT fk_3a9eaa254d; |
|
|
|
-- Шаг 3: Удаляем последовательность |
|
DROP SEQUENCE IF EXISTS ci_stages_id_seq; |
|
|
|
-- Шаг 4: Создаём новую последовательность |
|
CREATE SEQUENCE ci_stages_id_seq |
|
START WITH 14876 -- или другое значение, большее максимального id |
|
INCREMENT BY 1 |
|
NO MINVALUE |
|
NO MAXVALUE |
|
CACHE 1; |
|
|
|
-- Шаг 5: Привязываем последовательность к колонке id |
|
ALTER TABLE ci_stages ALTER COLUMN id SET DEFAULT nextval('ci_stages_id_seq'); |
|
|
|
-- Шаг 6: Восстанавливаем внешний ключ |
|
ALTER TABLE p_ci_builds |
|
ADD CONSTRAINT fk_3a9eaa254d FOREIGN KEY (stage_id) REFERENCES ci_stages(id) ON DELETE CASCADE; |
|
|
|
-- Шаг 7: Сбрасываем значение последовательности на максимальный id |
|
SELECT setval('ci_stages_id_seq', (SELECT MAX(id) FROM ci_stages)); |
|
|
|
ALTER SEQUENCE ci_stages_id_seq OWNER TO gitlab; |
|
ALTER SEQUENCE ci_stages_id_seq OWNED BY ci_stages.id; |
|
--========================================================================================== |
|
EXPLAIN ANALYZE |
|
UPDATE |
|
tbl |
|
SET |
|
val = val + 1 |
|
FROM |
|
( |
|
SELECT |
|
ctid |
|
FROM |
|
tbl |
|
WHERE |
|
id IN (1, 2, 3) |
|
ORDER BY |
|
id |
|
FOR UPDATE -- блокировка |
|
) lc |
|
WHERE |
|
tbl.ctid = lc.ctid; -- поиск по физической позиции записи |
|
--========================================================================================== |
|
select * from foo where not exists (select 1 from bar where foo.col = bar.x); |
|
SELECT * FROM blah WHERE timestampcol >= '2018-06-01' AND timestampcol < '2018-06-08' |
|
|
|
SELECT column1, column2, ...FROM table1 WHERE EXISTS (SELECT 1 FROM table2 WHERE table1.column = table2.column); |
|
SELECT column1, column2, ...FROM table1WHERE column IN (SELECT column FROM table2); |
|
|
|
SELECT column1, column2,...FROM table1 LEFT JOIN table2 ON table1.column_name = table2.column_name WHERE table2.column_name IS NULL; |
|
Use text, or a domain over text, with CHECK(length(VALUE)=3) or CHECK(VALUE ~ '^[[:alpha:]]{3}$') or similar. |
|
--========================================================================================== |
|
select row_number() over() id, student FROM seats order by if(mod(id, 2) = 0, id-1, id+1); |
|
--========================================================================================== |
|
select c.name FROM customers c JOIN (select customerId from orders group by customerId having count(orderId) > 2) o |
|
on c.customerId = o.customerId |
|
where c.city = 'New Your'; |
|
--========================================================================================== |
|
CREATE VIEW car AS (SELECT * FROM vehicle WHERE type='car'); |
|
|
|
CREATE VIEW universal_comedies AS |
|
SELECT * |
|
FROM comedies |
|
WHERE classification = 'U' |
|
WITH LOCAL CHECK OPTION; |
|
|
|
CREATE VIEW pg_comedies AS |
|
SELECT * |
|
FROM comedies |
|
WHERE classification = 'PG' |
|
WITH CASCADED CHECK OPTION; |
|
|
|
CREATE VIEW comedies AS |
|
SELECT f.*, |
|
country_code_to_name(f.country_code) AS country, |
|
(SELECT avg(r.rating) |
|
FROM user_ratings r |
|
WHERE r.film_id = f.id) AS avg_rating |
|
FROM films f |
|
WHERE f.kind = 'Comedy'; |
|
|
|
CREATE RECURSIVE VIEW public.nums_1_100 (n) AS |
|
VALUES (1) |
|
UNION ALL |
|
SELECT n+1 FROM nums_1_100 WHERE n < 100; |
|
|
|
create rule car_insert as on insert to car do instead |
|
insert into vehicle(type, top_speed, license_plate) |
|
values('car', new.top_speed, new.license_plate); |
|
insert into car(top_speed, license_plate) values(160,'v4n1ty'); |
|
table car; |
|
|
|
CREATE FUNCTION insertCar() RETURNS trigger AS $$ |
|
BEGIN |
|
INSERT INTO vehicle |
|
(type, top_speed, license_plate) |
|
VALUES |
|
('car', new.top_speed, new.license_plate); |
|
END; |
|
$$ LANGUAGE plpgsql; |
|
|
|
CREATE TRIGGER insertCarTrigger INSTEAD OF INSERT ON car |
|
FOR EACH ROW EXECUTE PROCEDURE insertCar(); |
|
|
|
The view must have exactly one entry in its FROM list, which must be a table or another updatable view. |
|
The view definition must not contain WITH, DISTINCT, GROUP BY, HAVING, LIMIT, or OFFSET clauses at the top level. |
|
The view definition must not contain set operations (UNION, INTERSECT or EXCEPT) at the top level. |
|
The view's select list must not contain any aggregates, window functions or set-returning functions. |
|
--========================================================================================== |
|
updates salary set sex = case sex when 'm' then 'f' else 'm' end; |
|
--========================================================================================== |
|
select * from (select name, salaray, dense_rank() over (order by salary desc) as rank from employees) as sub where rank = 1; |
|
select name, salary from employees order by salaray desc limit 1 offset 2; |
|
--========================================================================================== |
|
select * from employee e where day(e.created_at) in (1, 2, 3, 4, 5, 6, 7, 8); |
|
select customer_id from customer group by customer_id having count(distinct product_key) = (select count(*) from product); |
|
--========================================================================================== |
|
SELECT |
|
ROUND ((LENGTH (desc) - LENGTH (REPLACE (desc, ‘val‘,‘‘) )) / LENGTH(‘val‘)) AS c |
|
FROM items; |
|
--========================================================================================== |
|
select a.name as emp_name, b.name as man_name from employees a |
|
join employees b on a.manager_id = b.id; |
|
--========================================================================================== |
|
SELECT pg_export_snapshot(); |
|
BEGIN ISOLATION LEVEL REPEATABLE READ; |
|
SET TRANSACTION SNAPSHOT '00000004-0000006E-1'; |
|
--========================================================================================== |
|
DO $$ |
|
DECLARE |
|
cur CURSOR FOR SELECT id, name FROM users; |
|
rec RECORD; |
|
BEGIN |
|
OPEN cur; |
|
LOOP |
|
FETCH cur INTO rec; |
|
EXIT WHEN NOT FOUND; |
|
RAISE NOTICE 'User: %, Name: %', rec.id, rec.name; |
|
END LOOP; |
|
CLOSE cur; |
|
END $$; |
|
--========================================================================================== |
|
select employee_id, mode() within group (ORDER BY customer_id) |
|
FROM orders |
|
GROUP BY employee_id; |
|
--========================================================================================== |
|
1) Переносим базу PostgreSQL и схему нужной базы: |
|
pg_dumpall --database=postgres --host=x.x.x.x --no-password --globals-only --no-privileges | psql |
|
pg_dump --dbname name_db --host=x.x.x.x --no-password --create --schema-only | psql |
|
2) Создаём публикацию базы на мастере: |
|
CREATE PUBLICATION name_pub FOR ALL TABLES; |
|
3) Cоздаём подписку на реплике: |
|
CREATE SUBSCRIPTION name_sub CONNECTION 'host=x.x.x.x dbname=name_db' PUBLICATION name_pub; |
|
4) Проверяем публикацию на мастере: |
|
select * from pg_catalog.pg_publication; |
|
5) Проверяем подписку на реплике: |
|
SELECT * FROM pg_stat_subscription; |
|
--========================================================================================== |
|
1) MASTER: |
|
\c name_db |
|
select usename,client_addr,state,replay_lag from pg_stat_replication; |
|
select slot_name,slot_type,active from pg_replication_slots; |
|
2) MASTER: |
|
\c name_db |
|
select pg_create_logical_replication_slot('logical_replica_slot', 'pgoutput'); |
|
select * from pg_replication_slots; |
|
!!!check slot for database? |
|
3) MASTER: |
|
\c name_db |
|
CREATE PUBLICATION name_db_pub FOR ALL TABLES; |
|
4) REPLICA: |
|
\c postgres |
|
SELECT pg_promote(); |
|
5) REPLICA: |
|
Берем LSN из 13-й версии psql и продвигаем слот через pg_replication_slot_advance: |
|
cat /var/log/postgresql/postgresql-13-main.log | grep "redo done at" |
|
6) MASTER: |
|
\c name_db |
|
select pg_replication_slot_advance('logical_replica_slot', '2BB97/CF307EA0'); |
|
7) MASTER: |
|
Удаляем старый слот потоковой реплики: |
|
select pg_drop_replication_slot('repmgr_slot_5'); |
|
8) REPLICA: |
|
Установка 16-й версии: |
|
apt-get install -y postgresql-16 postgresql-16-repack postgresql-16-repmgr postgresql-client-16 |
|
9) REPLICA: |
|
Проверка: |
|
pg_lsclusters |
|
10) REPLICA |
|
Подготовка старого инстанса: |
|
psql -U postgres -p 5432 << EOF |
|
drop database pghero; |
|
\connect name_db |
|
drop extension pg_repack cascade; |
|
drop extension pg_stat_statements cascade; |
|
drop schema pghero cascade; |
|
drop schema repack cascade; |
|
drop schema okmeter cascade; |
|
drop schema repmgr cascade; |
|
\connect postgres |
|
drop extension pg_repack cascade; |
|
drop extension pg_stat_statements cascade; |
|
drop schema pghero cascade; |
|
drop schema repack cascade; |
|
drop schema okmeter cascade; |
|
drop schema repmgr cascade; |
|
EOF |
|
Иначе при переносе данных на новый инстанс будут ошибки при создании представлений и прочего. |
|
pg_restore: creating VIEW "pghero.pg_stat_activity" |
|
pg_restore: while PROCESSING TOC: |
|
pg_restore: from TOC entry 203; 1259 19999367 VIEW pg_stat_activity postgres |
|
pg_restore: error: could not execute query: ERROR: column reference "backend_type" is ambiguous |
|
LINE 34: "pg_stat_activity"."backend_type" |
|
11) REPLICA: |
|
Стоп PostgreSQL: |
|
systemctl stop postgresql |
|
12) REPLICA: |
|
Логин под юзером PostgreSQL и работа по апгрейду: |
|
su postgres |
|
13) REPLICA: |
|
Проверка возможности обновления: |
|
/usr/lib/postgresql/16/bin/pg_upgrade \ |
|
--old-datadir=/var/lib/postgresql/13/main \ |
|
--new-datadir=/var/lib/postgresql/16/main \ |
|
--old-bindir=/usr/lib/postgresql/13/bin \ |
|
--new-bindir=/usr/lib/postgresql/16/bin \ |
|
--old-options '-c config_file=/etc/postgresql/13/main/postgresql.conf' \ |
|
--new-options '-c config_file=/etc/postgresql/16/main/postgresql.conf' \ |
|
--check |
|
14) REPLICA: |
|
Апгрейд путём создания жёстких ссылок на inode файлов: |
|
/usr/lib/postgresql/16/bin/pg_upgrade \ |
|
--old-datadir=/var/lib/postgresql/13/main \ |
|
--new-datadir=/var/lib/postgresql/16/main \ |
|
--old-bindir=/usr/lib/postgresql/13/bin \ |
|
--new-bindir=/usr/lib/postgresql/16/bin \ |
|
--old-options '-c config_file=/etc/postgresql/13/main/postgresql.conf' \ |
|
--new-options '-c config_file=/etc/postgresql/16/main/postgresql.conf' \ |
|
--link |
|
15) REPLICA: |
|
Выход из-под юзера PostgreSQL: |
|
exit |
|
16) REPLICA: |
|
Правка конфига 16-й версии и смена портов: |
|
rsync -av /etc/postgresql/13/main/ /etc/postgresql/16/main/ |
|
sed -i '/stats_temp_directory/d' /etc/postgresql/16/main/postgresql.conf |
|
sed -i '/vacuum_defer_cleanup_age/d' /etc/postgresql/16/main/postgresql.conf |
|
sed -i 's/pg_stat_statements,pg_repack/pg_stat_statements/' /etc/postgresql/16/main/postgresql.conf |
|
sed -i 's/\/13\//\/16\//' /etc/postgresql/16/main/postgresql.conf |
|
sed -i 's/5433/5432/' /etc/postgresql/16/main/postgresql.conf |
|
sed -i 's/13-main/16-main/' /etc/postgresql/16/main/postgresql.conf |
|
sed -i 's/13\/main/16\/main/' /etc/postgresql/16/main/postgresql.conf |
|
sed -i 's/5432/5433/' /etc/postgresql/13/main/postgresql.conf |
|
17) REPLICA: |
|
Старт службы PostgreSQL: |
|
systemctl start postgresql |
|
18) REPLICA: |
|
Логин под юзером PostgreSQL: |
|
su postgres |
|
19) REPLICA: |
|
Обновление Optimizer statistics, который не переносится из старого инстанса: |
|
/usr/lib/postgresql/16/bin/vacuumdb --all --analyze-in-stages |
|
20) REPLICA: |
|
Удаление старого инстанса: |
|
./delete_old_cluster.sh |
|
rm -rf /etc/postgresql/13/main |
|
21) REPLICA: |
|
Выход из-под юзера PostgreSQL: |
|
exit |
|
22) REPLICA: |
|
\c name_db |
|
CREATE SUBSCRIPTION name_db_sub CONNECTION 'host=x.x.x.x dbname=name_db' PUBLICATION name_db_pub WITH (copy_data=false, slot_name='logical_replica_slot', create_slot=false); |
|
--========================================================================================== |
|
select |
|
rc1_0.id, |
|
rc1_0.created_at, |
|
rc1_0.key, |
|
rc1_0.value |
|
from |
|
( SELECT |
|
ss.id, |
|
ss.key, |
|
ss.value, |
|
ss.created_at |
|
FROM |
|
system_settings AS ss |
|
INNER JOIN |
|
( SELECT |
|
ss2.key as k2, MAX(ss2.created_at) as ca2 |
|
FROM |
|
system_settings ss2 |
|
GROUP BY |
|
ss2.key ) AS t |
|
ON t.k2 = ss.key |
|
AND t.ca2 = ss.created_at |
|
WHERE |
|
ss.type = 'SYSTEM' |
|
AND ss.active IS TRUE ) rc1_0 |
|
where |
|
rc1_0.key=? |
|
--========================================================================================== |
|
select |
|
dense_rank() over w as rank, |
|
first_name, department.name as dep_name, |
|
salary |
|
from employee |
|
join department using(dep_id) |
|
window w as (order by salary desc) |
|
order by rank, emp_id; |
|
--========================================================================================== |
|
select * from pg_stats where tablename = 'pgconf' and attname = 'fk_id'; |
|
create index fk_not_null on pgconf(fk_id) where fk_id is not null; |
|
--========================================================================================== |
|
create index simple on pgconf((state = 'state')); |
|
create index normal on pgconf(created_at, state); |
|
create index complex on pgconf(created_at) where state != 'state'; |
|
--========================================================================================== |
|
delete from person p1 using person p2 where p1.email = p2.email and p1.id > p2.id; |
|
--========================================================================================== |
|
with highest_salary as ( |
|
select max(salary) as salary |
|
from employee |
|
) |
|
select max(salary) |
|
from employee |
|
where salary < (select salary from highest_salary); |
|
--========================================================================================== |
|
USE <database> |
|
SELECT * FROM fn_my_permissions(NULL, 'DATABASE'); |
|
|
|
sp_configure 'show advanced options', '1' |
|
RECONFIGURE |
|
#This enables xp_cmdshell |
|
sp_configure 'xp_cmdshell', '1' |
|
RECONFIGURE |
|
--========================================================================================== |
|
SELECT * |
|
FROM ( |
|
SELECT |
|
post_id, |
|
post_title, |
|
comment_id, |
|
comment_review, |
|
DENSE_RANK() OVER (ORDER BY p_pc.comment_count DESC) AS ranking |
|
FROM ( |
|
SELECT |
|
p.id AS post_id, |
|
p.title AS post_title, |
|
pc.id AS comment_id, |
|
pc.review AS comment_review, |
|
COUNT(post_id) OVER(PARTITION BY post_id) AS comment_count |
|
FROM post p |
|
LEFT JOIN post_comment pc ON p.id = pc.post_id |
|
WHERE p.title LIKE 'SQL%' |
|
) p_pc |
|
) p_pc_r |
|
WHERE p_pc_r.ranking <= 2 |
|
ORDER BY post_id, comment_id |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |
|
--========================================================================================== |