Syntax details for the DB1 (databases) course at HdM Stuttgart
Felicitas Pojtinger
2022-02-01
“so basically i am monkey” - monke, monkeeee
Most of the following is based on the Oracle Tutorial.
Run the following to get the commands to drop all tables and their constraints:
begin
for i in (select index_name from user_indexes where index_name not like '%_PK') loop
execute immediate 'drop index ' || i.index_name;
end loop;
for i in (select trigger_name from user_triggers) loop
execute immediate 'drop trigger ' || i.trigger_name;
end loop;
for i in (select view_name from user_views) loop
execute immediate 'drop view ' || i.view_name;
end loop;
for i in (select table_name from user_tables) loop
execute immediate 'drop table ' || i.table_name || ' cascade constraints';
end loop;
execute immediate 'purge recyclebin';
end;
Now copy & paste the output into SQL Developer’s SQL worksheet and hit F5.
Operator | Description |
---|---|
= | Equality |
!=,<> | Inequality |
> | Greater than |
< | Less than |
>= | Greater than or equal to |
<= | Less than or equal to |
IN | Equal to any value in a list of values |
ANY/ SOME/ ALL | Compare a value to a list or subquery. It must be preceded by another operator such as =, >, <.j |
NOT IN | Not equal to any value in a list of values |
[NOT] BETWEEN n and m | Equivalent to [Not] >= n and <= y. |
[NOT] EXISTS | Return true if subquery returns at least one row |
IS [NOT] NULL | NULL test |
An inner join matches stuff in both tables:
A left (outer) join matches everything in the left tables plus what matches in the right table:
This left (outer) join matches everything that is in the left table and not in the right table:
A right (outer) join matches everything in the right join plus what matches in the left table:
This right (outer) join matches everything that is in the right table and not in the left table:
A full (outer) join merges both tables:
This full (outer) join merges both tables and removes those rows which are in both:
In addition to the on keyword you can also use the using keyword if the PK and FK are the same:
You can also use multiple on or using statements:
If you use the on keyword, use and
for
multiples!
You can also create the Cartesian product:
It is also possible to do a self join:
What is the difference between join
and
union
? join
merges horizontally (there are
more columns than before, maybe also more rows), union
merges vertically (there are more rows than before, but the column count
stays the same).
union
is similar to T1 | T2
in
TypeScript; you can use order by and union to remove duplicates, but
note that we have to use select two times:
union all
is similar to T1 & T2
in
TypeScript; it keeps duplicates:
Wish to find the difference between two tables? Use
intersect
:
Wish to subtract one table from another table? Use
minus
:
You can alias long column names with
select mylongname as name from contacts
or just
select mylongname name from contacts
. The as
keyword is optional. Full-text column names are supported by enclosing
in ““. as can also format strings:
select first_name || ' ' || last_name as "Name" from employees;
yields Alice, Bob and System.
You can also create a table alias (using
from employees e
), but you CAN’T USE the as
keyword.
The Oracle equivalent of filter is
fetch n next rows only
:
select * from products order by list_price desc fetch next 5 rows only;
.
You may also use the
fetch next n percent rows only
:
Filtering by for example a quantity, and you only want the first
10 “condition matches”? Use
fetch n next rows with ties
:
Need Pagination? Use offset:
Want to extract a year from a date? Use extract
:
Want to get the current date? Use current_date
:
The to_char
function can convert dates (and
timestamps) to chars:
The to_date
function can convert chars to dates:
Alternatively, the date literal uses the YYYY-MM-DD
format and does not require format specs:
You can get the current date with sysdate
:
You can get the current date & time with
datelocaltimestamp
:
The current time zone is available with
sessiontimezone
:
The timestamp
literal uses the
YYYY-MM-DD HH24:MI:SS.FF
format:
You may also append the timezone (But keep in mind that timestamp with time zone is the column type in this case):
The interval
literal can be used to create
intervals:
Using the months_between
function, the count of
months between two dates can be computed.
=
, NOT ==
.select product_name as "Product Name", list_price - standard_cost as "Gross Profit" from products order by "Gross Profit"
You can use ()
in where
clauses to
prioritize:
The in
keyword is a useful tool for sub collections
and subqueries:
select * from orders where salesman_id in (54, 55, 56) order by order_id;
select * from orders where salesman_id not in (54, 55, 56) order by order_id; (you can use not)
select * from employees where employee_id in ( select distinct salesman_id from orders where status = 'Canceled' ) order by first_name;
(you can of course also use not)between
can also be used for dates:
... like '%Asus%'
(note the 's) is basically a
full-text search.
Some examples of like
(you can use not
for all of them):
select * from contacts where last_name like 'St%'
select * from contacts where last_name like '%St'
select * from contacts where last_name like '%St%'
select * from contacts where last_name like 'Po_tinger'
(_
matches any one character)select * from contacts where lower(last_name) like 'st%'
select * from contacts where upper(last_name) like 'st%'
select * from discounts where discount_message like '%%%'
(returns everything)select * from discounts where discount_message like '%%%' escape '!'
(returns everything that includes the string ‘%’)You can compare against null with is null
(= NULL
does not work). You can negate with
not
.
You can use functions like upper
and dates when
ordering.
The group by
keyword can be used to find unique
data:
By combining group by
with count
you
can count the amount of unique data:
group by
can also be used with the
where
keyword:
where
can NOT APPEAR AFTER group by
;
use the having keyword instead.
The having
keyword enables you to filter like with
where
, but after the group by
keyword like
so:
Multiple order by statements? First ordered by first statement, then “sub-ordered” by the second (last name the same -> now first name is evaluated).
Want to have nulls first when ordering? Use nulls first or nulls last as the suffix.
Removal of duplicates is done with select distinct
.
When multiple columns are being selected, use only one distinct keyword
at the start. Multiple nulls are filtered (Null = Null).
You can count the amount of rows with the count()
function:
The sum
function can be used to calculate a
total:
It can also be used to calculate a total per row (the group by
order_id
part is required;
group by order_value
does not work):
It is a good idea to always specify the columns when inserting:
You can also “insert from select” using
insert into
:
It’s even possible to “create a table from select” using
create table x as
, basically coping its schema
(where 1 = 0 skips
copying the rows):
Using insert all, it is possible to insert multiple rows at once (note the lack of commas between the into keywords. Here, the subquery is ignored/a placeholder.):
You can also use conditions based on the subquery
(insert first
is the equivalent of a switch case.):
Using case
it is possible to create if/else
constructs:
case
is also useful for conditional grouping:
case
also evaluates to an expression, so you can use
it for conditional updates:
You can extract substrings with substr
:
select substr('Alex', 1, 1) from dual;
Stuff like select upper('uwu') from dual
can come in
handy.
Using round
it is possible to round numbers (returns
5.23):
You can use replace
to replace strings:
You can use the floor
, round
and
ceil
functions to get rounded values.
generated by default as identity
is quite useful for
auto-incrementing columns such as PKs:
generated always as identity
is the same but does
not allow setting it manually.
You can use desc mytable
to show the schema for a
table.
alter table
can be used to add columns using
add:
You can also add multiples at once (note that there is no column keyword):
modify
can change the column type (note that there
is no column keyword):
drop column
can be used to remove a column
rename column
can be used to rename a column:
rename to
can be used to rename a table:
rename promotions to promotions_two
is an
alternative syntax.
You can use the default keyword to set a default value:
A more efficient logical version of drop column is set unused column:
You can now drop it using:
If you want to physically drop a column, use
drop
:
You can create virtual columns in regular tables without using
views with alter table x add ... as
(note the required
(
after the as
keyword):
The size of a varchar2
is adjustable afterwards
(note that this checks if any current varchar2
s are larger
than the new size and fails if they are.):
You can drop a table with drop table
:
Appending purge
clears the recycle bin; appending
cascade constraints
drop all related constraints.
You can clear a table using truncate table
:
The same limitations as with drop table concerning constraints apply, so appending cascade (WITHOUT constraints) drops all related ones.
You can clear the recycle bin with:
It is possible to add constraints (any constraints, a primary key in this example) after creating a table with add constraint:
You may remove a constraint with
drop constraint
:
Instead of removing it, you can also use
disable constraint
:
And re-enable it with enable constraint
:
You can also add foreign key constraints:
Using a check constraint, arbitrary expressions can be evaluated:
A unique constraint prevents unwanted duplicates:
With a not null constraint, fuzzy logic can be avoided; it is however best to define nullable fields at schema creation, as the syntax differs from the add constraint/drop constraint logic above:
You can remove them by modifying it to null explicitly:
number(1,0)
.number
type is used for all types of numbers by
specifying precision and scale: number(6)
(or
number(6,0)
) is a signed integer fitting 6 digits,
number(6,2)
is a float with two digits precision. The DB
doesn’t just cut of numbers, it rounds them.float(2)
is equal to number(38,2)
. The
argument is in bits instead of digits though.lengthdb
function can be used to get the length of
field in bytes.char(10)
or name
char(10 bytes)
, meaning that a char always takes up the
amount of bytes set. nchar
is the same but UTF-8 or UTF-16
any doesn’t take bytes.varchar2
type also takes an argument for the length
in bytes, which in ASCII corresponds to the amount of characters.
nvarchar2
is the same but UTF-8 or UTF-16 and doesn’t take
bytes.You can create a view with
create view x as select ...
:
If used with create or replace view
, upserts are
possible.
By appending with read only
, you can prevent data
modifications:
drop view x
removes the view.
Deletions and updates on views are usually fine, but inserts can
often be not that useful due to fields being excluded from the view; see
instead of
triggers later on for a solution;
Subqueries can be used in selects:
They can also be used in updates:
You can create an index with create index
:
You can also create an index spanning multiple columns:
You can drop an index with drop index
:
Block structure:
The most simple example is as follows:
Use put_line
from the dmbs_output
package to print to stdout.
You can use the declare section for variables:
The exception
block is used to handle exceptions,
for example zero_divide
for divisions by zero
(when others then
handles unexpected other exceptions):
You always have to specify an execution section; use
null
for a no-op:
You can use --
for single line comments and
/*
for multi line comments.
PL/SQL extends SQL by adding a boolean type (which can have the values true, false and null).
Variables need not be given a value at declaration if they are nullable:
You can use default
as an alternative to the
:=
operator when assigning variables in the declaration
section. DO NOT use =
when assignment, even re-assignment
also uses :=
.
If a variable is defined as not null, it can’t take a string of length 0:
Constants are created with the constant
keyword and
forbid reassignment:
Use select ... into
to fetch data into variables;
%TYPE
infers the type of a column:
if ... then ... end if
can be used for
branching:
Inline expressions are also supported:
Booleans need not be compared with my_bool = true
, a
simple if my_bool then
is fine.
elseif ... then
is NOT valid syntax;
elsif ... then
is valid syntax.
Statements may also be nested:
You may use the case
keyword for switch cases:
declare
grade char(1);
message varchar2(255);
begin
grade := 'A';
case grade
when 'A' then
message := 'Excellent';
when 'B' then
message := 'Great';
when 'C' then
message := 'Good';
when 'D' then
message := 'Fair';
when 'F' then
message := 'Poor';
else
raise case_not_found;
end case;
dbms_output.put_line(message);
end;
A label
/goto
equivalent is also
available:
The equivalent of the while
loop is the
loop
. exit
/continue
prevents an
infinite loop:
For loops can be done using the
for i in 0..100 loop ... end loop
syntax:
While loops work as you’d expect; but also require the
loop
keyword:
You can also use %ROWTYPE
to infer the type of a row
and select an entire row at once:
It is also possible to use OOP-style object/row creation thanks
to %ROWTYPE
:
You can create custom exceptions:
If you want to raise a custom exception, use
raise_application_error
:
Using sqlcode
and sqlerrm
you can get
the last exception’s code/error message.
Using cursors, you can procedurally process data:
declare
cursor sales_cursor is select * from sales;
sales_record sales_cursor%ROWTYPE;
begin
update customers set credit_limit = 0;
open sales_cursor;
loop
fetch sales_cursor into sales_record;
exit when sales_cursor%NOTFOUND;
update
customers
set
credit_limit = extract(year from sysdate)
where
customer_id = sales_record.customer_id;
end loop;
close sales_cursor;
end;
Complex exit logic can be avoided using the
for ... loop
:
Cursors can also have parameters:
declare
product_record products%rowtype;
cursor
product_cursor (
low_price number := 0,
high_price number := 100
)
is
select * from products where list_price between low_price and high_price;
begin
open product_cursor(50, 100);
loop
fetch product_cursor into product_record;
exit when product_cursor%notfound;
dbms_output.put_line(product_record.product_name || ': $' || product_record.list_price);
end loop;
close product_cursor;
end;
The DB can also lock fields for safe multiple access:
You can create procedures, which are comparable to functions:
These procedures can then be executed:
Or, without PL/SQL:
Once a procedure is no longer needed, it can be removed with
drop procedure
:
It is also possible to infer a row type using
sys_refcursor
and return rows with
dbms_sql.return_result
:
You can now call it:
Functions are similar, but require returning a value:
create or replace function
get_total_sales_for_year(year_arg integer)
return number
is
total_sales number := 0;
begin
select sum(unit_price * quantity) into total_sales
from order_items
inner join orders using (order_id)
where status = 'Shipped'
group by extract(year from order_date)
having extract(year from order_date) = year_arg;
return total_sales;
end;
You can call them from PL/SQL:
And remove them with drop function
:
Packages can be used to group function “interfaces” and variables:
You can now access the variables in the package with
.
:
In order to use functions in a package, you then have to create a package body, implementing it:
You can now access the functions in the package with
.
:
And the same is possible from PL/SQL:
You can drop a package with drop package
and a
package body with drop package body
:
Triggers follow a similar structure as procedures:
Using triggers, you can for example create a manual log after
operations with after update or delete on ...
:
create or replace trigger customers_audit_trigger
after update or delete
on customers
for each row
declare
transaction_type varchar2(10);
begin
transaction_type := case
when updating then 'update'
when deleting then 'delete'
end;
insert into audits(
table_name,
transaction_name,
by_user,
transaction_date
) values (
'customers',
transaction_type,
user,
sysdate
);
end;
Thanks to before update of ... on ...
, it is also
possible to do more complex checks before inserting:
In combination with when
, new
(not
available in delete
statements) and old
(not
available in insert
statements), it is also possible to
check based on the previous & current values:
create or replace trigger customers_credit_limit_trigger
before update of credit_limit
on customers
for each row
when (new.credit_limit > 0)
begin
if :new.credit_limit >= 2*:old.credit_limit then
raise_application_error(-20101, 'The new credit cannot be more than double the old credit!');
end if;
end;
Using instead of
triggers and
returning ... into ...
, you can also use views to safely
insert into multiple tables:
create or replace trigger create_customer_trigger
instead of insert on customers_and_contacts
for each row
declare
current_customer_id number;
begin
insert into customers(
name,
address,
website,
credit_limit
) values (
:new.name,
:new.address,
:new.website,
:new.credit_limit
) returning customer_id into current_customer_id;
insert into contacts(
first_name,
last_name,
email,
phone,
customer_id
) values (
:new.first_name,
:new.last_name,
:new.email,
:new.phone,
current_customer_id
);
end;
You can enable/disable a trigger with
alter trigger ... disable/enable
:
And completely remove it with drop trigger
:
It is also possible to enable/disable all triggers of a table
with alter table ... enable/disable all triggers
:
Maps are also possible in PL/SQL using table of
:
You can use mymap.first
and mymap.next
to iterate:
declare
type country_capitals_type
is table of varchar2(100)
index by varchar2(50);
country_capitals country_capitals_type;
current_country varchar2(50);
begin
country_capitals('China') := 'Beijing';
country_capitals('EU') := 'Brussels';
country_capitals('USA') := 'Washington';
current_country := country_capitals.first;
while current_country is not null loop
dbms_output.put_line(current_country || ': ' || country_capitals(current_country));
current_country := country_capitals.next(current_country);
end loop;
end;
Using varray
, it is also possible to create
arrays:
declare
type names_type is varray(255) of varchar2(20) not null;
names names_type := names_type('Albert', 'Jonathan', 'Judy');
begin
dbms_output.put_line('Length before append: ' || names.count);
names.extend;
names(names.last) := 'Alice';
dbms_output.put_line('Length after append: ' || names.count);
names.trim;
dbms_output.put_line('Length after trim: ' || names.count);
names.trim(2);
dbms_output.put_line('Length after second trim: ' || names.count);
names.delete;
dbms_output.put_line('Length after delete: ' || names.count);
end;