-- Order by -- Group by -- Over -- Over (Partition by) -- 1. Row_number -- 2. Rank -- 3. Dense Rank -- 4. First_value -- 5. Last_value -- 6. Nth_value -- 7. Lead -- 8. Lag -- 9. Cume_dist -- 10. Ntile -- 11. Percent_rank CREATE TABLE employee (empid INTEGER, name TEXT NOT NULL, dept TEXT NOT NULL, age INT); INSERT INTO employee VALUES (0001, 'Clark', 'Sales1',45); INSERT INTO employee VALUES (0001, 'Ava', 'Acc1',44); INSERT INTO employee VALUES (0001, 'Ava', 'HR1',2); INSERT INTO employee VALUES (0004, 'Clark', 'Sales2',25); INSERT INTO employee VALUES (0004, 'Dave', 'Acc2',25); INSERT INTO employee VALUES (0004, 'Ava', 'HR2',0); INSERT INTO employee VALUES (0005, 'Clark', 'Sales3',66); INSERT INTO employee VALUES (0005, 'Dave', 'Acc3',3); INSERT INTO employee VALUES (0005, 'Ava', 'HR3',3); -- select *, sqrt(age) from employee order by empid, name; -- DEMO OF AGGREGATING FUNCTIONS -- SELECT MIN(name) AS a, MAX(empid) AS b, AVG(dept) AS c, COUNT(*) AS d, SUM(dept) AS e FROM employee; -- 1 -- SELECT empid, MIN(age) FROM employee; -- 2 (>> throws error because we can't combine aggregated column and non-aggregated column in select 'without over or group by') -- SELECT empid, MIN(age) OVER() FROM employee; -- 3 (we can combine aggregated column and non-aggregated column in select 'with over()') -- SELECT empid, MIN(age) FROM employee GROUP BY empid; -- 4 (we can combine aggregated column and non-aggregated column in select 'with group by') -- SELECT empid, MIN(age) OVER() FROM employee GROUP BY empid; -- DEMO OF ORDER BY -- SELECT * FROM employee ORDER BY dept; -- 1 (works) -- SELECT MIN(age) FROM employee ORDER BY dept DESC; -- 2 (works) -- SELECT empid, MIN(age) OVER() FROM employee ORDER BY dept; -- 3 (works) -- DEMO OF GROUP BY -- SELECT * FROM employee GROUP BY empid; -- 1 (>> throws error because group by requires (un)grouped aggregated columns or grouped unaggregated columns in select) -- SELECT AVG(empid) FROM employee GROUP BY empid; -- 2 (we can select 'aggregated' version of the same column we are grouping in group by) -- SELECT empid FROM employee GROUP BY empid; -- 3 (we can select 'non-aggregated' version of the same column we are grouping in group by) -- SELECT dept, age, MIN(age) FROM employee GROUP BY empid; -- 4 (>> throws error because group by requires aggregated columns + grouped columns (optional) 'and nothing else' in select) -- SELECT empid, MIN(age) FROM employee GROUP BY empid; -- 5 (aggregated columns + grouped columns in select work with group by) -- SELECT empid, MIN(age) OVER() FROM employee GROUP BY empid; -- 6 (>> throws error because over has to be used only with aggregated version of 'grouped' column) -- SELECT empid OVER() FROM employee GROUP BY empid; -- 7 (>> throws error because over has to be used only with 'aggregated' version of grouped column) -- SELECT SUM(empid) OVER() FROM employee GROUP BY empid; -- 8 (over works with aggregated version of grouped column in group by) -- DEMO OF PARTITION BY -- SELECT * FROM employee PARTITION BY dept; -- 1 (>> throws error because can't be used without over) -- SELECT dept FROM employee PARTITION BY dept; -- 2 (>> throws error because can't be used without over) -- DEMO OF OVER -- SELECT empid OVER() FROM employee; -- 1 (>> throws error because OVER() can't be with non agg cols) -- SELECT empid OVER() FROM employee ORDER BY empid; -- 2 (>> throws error because OVER() can't be with non agg cols, even with order by) -- SELECT empid OVER() FROM employee GROUP BY empid; -- 3 (>> throws error because OVER() can't be with non agg cols, even with group by) -- SELECT MIN(empid) OVER() FROM employee; -- 4 (works well because OVER() can be with agg cols) -- SELECT MIN(empid) OVER() FROM employee GROUP BY empid; -- 4 (works well because OVER() can be with agg cols, even with group by) -- SELECT *, MIN(age) OVER() mi, MAX(age) OVER() ma, AVG(age) OVER() av, SUM(age) OVER() su, COUNT(age) OVER() co FROM employee; -- DEMO OF OVER(PARTITION BY) SELECT empid, dept, name, age, MIN(age) OVER(partition by empid, name) AS mi, MAX(age) OVER(partition by empid) AS ma, AVG(age) OVER(partition by name) AS av, SUM(age) OVER(partition by name) AS su, COUNT(age) OVER(partition by name) AS co FROM employee ORDER BY empid ASC; -- 1 (works) -- DEMO OF ROW_NUMBER, RANK, DENSE_RANK SELECT *, ROW_NUMBER() OVER(PARTITION BY empid ORDER BY age) as row1, RANK() OVER(PARTITION BY empid ORDER BY age) as rank1, DENSE_RANK() OVER(PARTITION BY empid ORDER BY age) as dense1 FROM employee ORDER BY empid; -- DEMO OF FIRST_VALUE, LAST_VALUE, NTH_VALUE SELECT *, FIRST_VALUE(age) OVER win AS first1, LAST_VALUE(age) OVER win AS last1, NTH_VALUE(age, 2) OVER win AS nth1 FROM employee WINDOW win AS (PARTITION BY empid ORDER BY age RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING); -- DEMO OF LEAD, LAG SELECT *, LEAD(age) OVER(PARTITION BY empid ORDER BY age) as next, -- in nth row, display value of (n+m)th row (basically mth leading row's value) with m being given in brackets. if n-m < 0 then use def value given in brackets. if no def value given, use NULL. LAG(age, 2, "i'm default") OVER(PARTITION BY empid ORDER BY age) as prev -- in nth row, display value of (n-m)th row (basically mth lagging row's value) with m being given in brackets. if n-m > len(table) then use def value given in brackets. if no def value given, use NULL. FROM employee ORDER BY empid; -- DEMO OF CUME_DIST, NTILE, PERCENT_RANK INSERT INTO employee VALUES (0005, 'Clark', 'Sales33',67); INSERT INTO employee VALUES (0005, 'Clark', 'Sales33',68); SELECT *, NTILE(2) OVER win AS ntile1, -- binning data into # of buckets given, if uneven then upper buckets prioritised PERCENT_RANK() OVER win AS percrank1, -- %ile rank when all data points compared among each other and sorted. 1st row 0 last row mostly 1. current row's percrank = (current row's nondense rank - 1)/(total rows - 1). how much % more/less expensive, etc. CUME_DIST() OVER win AS cumedist1 -- distri of current sets of rows compared to entire dataset. current row's cume_dist = (current row's nondense rank's higher side value/total rows). use case = which rows constitute top 30% data points. FROM employee WINDOW win AS (PARTITION BY empid ORDER BY age RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING); -- 1 (works) Frame Clause -- ALL-IN-ONE SELECT *, ROW_NUMBER() OVER win as row1, RANK() OVER win as rank1, DENSE_RANK() OVER win as dense1, FIRST_VALUE(age) OVER win AS first1, LAST_VALUE(age) OVER win AS last1, NTH_VALUE(age, 2) OVER win AS nth1, LEAD(age) OVER win as lead1, LAG(age, 2, "i'm default") OVER win as lag1, NTILE(2) OVER win as ntile1, PERCENT_RANK() OVER win as percrank1, CUME_DIST() OVER win as cume1 FROM employee WINDOW win AS (PARTITION BY empid ORDER BY age RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING); -- DEMO OF FRAME CLAUSE INSERT INTO employee VALUES (0001, 'Mark', 'Sales11',71); INSERT INTO employee VALUES (0004, 'Mark', 'Sales22',78); DELETE FROM employee WHERE age = 68; SELECT empid, name, dept, age, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS upuf, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS upcr, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN UNBOUNDED PRECEDING AND 2 FOLLOWING) AS up2f, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) AS cruf, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN CURRENT ROW AND CURRENT ROW) AS crcr, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN CURRENT ROW AND 2 FOLLOWING) AS cr2f, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN 2 PRECEDING AND UNBOUNDED FOLLOWING) AS 2puf, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN 2 PRECEDING AND CURRENT ROW) AS 2pcr, MAX(age) OVER (PARTITION BY empid ORDER BY AGE ROWS BETWEEN 2 PRECEDING AND 2 FOLLOWING) AS 2p2f FROM employee ORDER BY empid ASC; SELECT empid, name, dept, age, MAX(age) OVER (PARTITION BY empid RANGE BETWEEN UNBOUNDED PRECEDING AND UNBOUNDED FOLLOWING) AS upuf, MAX(age) OVER (PARTITION BY empid RANGE BETWEEN UNBOUNDED PRECEDING AND CURRENT ROW) AS upcr, MAX(age) OVER (PARTITION BY empid ORDER BY AGE RANGE BETWEEN UNBOUNDED PRECEDING AND 50 FOLLOWING) AS up50f, MAX(age) OVER (PARTITION BY empid ORDER BY AGE RANGE BETWEEN CURRENT ROW AND UNBOUNDED FOLLOWING) AS cruf, MAX(age) OVER (PARTITION BY empid ORDER BY AGE RANGE BETWEEN CURRENT ROW AND CURRENT ROW) AS crcr, MAX(age) OVER (PARTITION BY empid ORDER BY AGE RANGE BETWEEN CURRENT ROW AND 50 FOLLOWING) AS cr50f, MAX(age) OVER (PARTITION BY empid ORDER BY AGE RANGE BETWEEN 50 PRECEDING AND UNBOUNDED FOLLOWING) AS 50puf, MAX(age) OVER (PARTITION BY empid ORDER BY AGE RANGE BETWEEN 50 PRECEDING AND CURRENT ROW) AS 50pcr, MAX(age) OVER (PARTITION BY empid ORDER BY AGE RANGE BETWEEN 50 PRECEDING AND 50 FOLLOWING) AS 50p50f FROM employee ORDER BY empid ASC;
Write, Run & Share MySQL queries online using OneCompiler's MySQL online editor and compiler for free. It's one of the robust, feature-rich online editor and compiler for MySQL. Getting started with the OneCompiler's MySQL editor is really simple and pretty fast. The editor shows sample boilerplate code when you choose language as 'MySQL' and start writing queries to learn and test online without worrying about tedious process of installation.
MySQL is a open-source, free and very popular relational database management system which is developed, distributed and supported by Oracle corporation.
CREATE TABLE table_name (
column1 datatype,
column2 datatype,
....);
CREATE TABLE EMPLOYEE (
empId INTEGER PRIMARY KEY,
name TEXT NOT NULL,
dept TEXT NOT NULL
);
ALTER TABLE Table_name ADD column_name datatype;
INSERT INTO EMPLOYEE VALUES (0001, 'Dave', 'Sales');
TRUNCATE table table_name;
DROP TABLE table_name;
RENAME TABLE table_name1 to new_table_name1;
--Line1;
/* Line1,
Line2 */
INSERT INTO table_name (column1, column2, column3, ...) VALUES (value1, value2, value3, ...);
Note: Column names are optional.
INSERT INTO EMPLOYEE VALUES (0001, 'Ava', 'Sales');
SELECT column1, column2, ...
FROM table_name
[where condition];
SELECT * FROM EMPLOYEE where dept ='sales';
UPDATE table_name
SET column1 = value1, column2 = value2, ...
WHERE condition;
UPDATE EMPLOYEE SET dept = 'Sales' WHERE empId='0001';
DELETE FROM table_name where condition;
DELETE from EMPLOYEE where empId='0001';
CREATE INDEX index_name on table_name(column_name);
CREATE UNIQUE INDEX index_name on table_name(column_name);
DROP INDEX index_name ON table_name;
Creating a View:
CREATE VIEW View_name AS
Query;
SELECT * FROM View_name;
ALTER View View_name AS
Query;
DROP VIEW View_name;
CREATE TRIGGER trigger_name trigger_time trigger_event
ON tbl_name FOR EACH ROW [trigger_order] trigger_body
/* where
trigger_time: { BEFORE | AFTER }
trigger_event: { INSERT | UPDATE | DELETE }
trigger_order: { FOLLOWS | PRECEDES } */
DROP TRIGGER [IF EXISTS] trigger_name;
CREATE PROCEDURE sp_name(p1 datatype)
BEGIN
/*Stored procedure code*/
END;
CALL sp_name;
DROP PROCEDURE sp_name;
SELECT * FROM TABLE1 INNER JOIN TABLE2 where condition;
SELECT * FROM TABLE1 LEFT JOIN TABLE2 ON condition;
SELECT * FROM TABLE1 RIGHT JOIN TABLE2 ON condition;
SELECT select_list from TABLE1 CROSS JOIN TABLE2;