Skip to content

Commit

Permalink
Browse files Browse the repository at this point in the history
  • Loading branch information
hope-fisher committed Dec 13, 2024
2 parents ee8d3e2 + a7c2bad commit 0f4d1f1
Show file tree
Hide file tree
Showing 22 changed files with 316 additions and 50 deletions.
6 changes: 4 additions & 2 deletions db-23ai-fundamentals/intro/sql-enhancements.md
Original file line number Diff line number Diff line change
Expand Up @@ -19,11 +19,13 @@ In Oracle Database 23ai, several key enhancements have been introduced to the SQ

- **Boolean Data Type:** The introduction of a new boolean data type enhances data modeling capabilities, allowing for more efficient representation and manipulation of boolean values.

- **IF EXISTS:** The IF EXISTS statements are powerful tools for executing SQL commands based on the existence or non-existence of certain conditions or objects inside the database.

- **Table Value Constructors:** Table value constructors provide a convenient way to specify multiple rows in insert, select, or merge statements, simplifying data manipulation tasks.

- **Direct Joins in Updates:** Streamlined syntax for performing direct joins in update operations simplifies query construction and improves code readability.

- **IF EXISTS:** The IF EXISTS statements are powerful tools for executing SQL commands based on the existence or non-existence of certain conditions or objects inside the database.
- **DML RETURNING Clause Enhancements:** The `RETURNING INTO` clause for `INSERT`, `UPDATE`, `DELETE`, and `MERGE` statements has been enhanced to report old and new values affected by the respective statement. This allows developers to use a uniform approach for each of these DML types to obtain values before and after statement execution, enhancing efficiency and reducing the database workload.

You may now **proceed to the next lab**

Expand All @@ -38,4 +40,4 @@ For further exploration of Oracle Database features and enhancements, visit:
## Acknowledgements
* **Author** - Killian Lynch, Database Product Management
* **Contributors** - Dom Giles, Distinguished Database Product Manager
* **Last Updated By/Date** - Killian Lynch, January 2024
* **Last Updated By/Date** - Killian Lynch, December 2024
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
144 changes: 97 additions & 47 deletions db-23ai-fundamentals/new-boolean/new-boolean.md
Original file line number Diff line number Diff line change
Expand Up @@ -2,9 +2,9 @@

## Introduction

Welcome to the Boolean Data Type Lab for Oracle Database 23ai! In this lab, you will get some hands on experience with the boolean data types in Oracle Database 23ai.
Welcome to the Boolean Data Type Lab for Oracle Database 23ai! In this lab, you will get some hands on experience with the boolean data type in Oracle Database 23ai.

Oracle Database 23ai introduces native support for boolean data types which expands the capabilities of SQL and PL/SQL. The boolean data type standardizes the storage of Yes and No values and makes it easier to develop on the Oracle Database
Oracle Database 23ai introduces native support for boolean data types which expands the capabilities of SQL and PL/SQL. The boolean data type standardizes the storage of true, false, and null values and makes it easier to develop on the Oracle Database

Estimated Lab Time: 10 minutes

Expand All @@ -15,112 +15,162 @@ In this lab, you will explore the boolean data type introduced in Oracle Databas
- Access to Oracle Database 23ai environment.
- Basic understanding of SQL and PL/SQL.

## Task 1: Lab Setup
## Task 1: Working with the boolean data type

1. If you haven't done so already, from the Autonomous Database home page, **click** Database action and then **click** SQL.
1. If you haven't done so already, from the Autonomous Database home page, **click** Database actions and then **click** SQL.
![click SQL](images/im1.png =50%x*)

Using the ADMIN user isn’t typically advised due to the high level of access and security concerns it poses. **However**, for this demo, we’ll use it to simplify the setup and ensure we can show the full range of features effectively.
Using the ADMIN user isn’t typically advised due to the high level of access and security concerns it poses. **However**, for this demo, we’ll use it to simplify the setup and ensure we can show the full range of features effectively.

2. Before we begin, this lab will be using Database Actions Web. If you're unfamiliar, please see the picture below for a simple explanation of the tool. You can click on the photo to enlarge it.

![click SQL](images/simple-db-actions.png =50%x*)

2. Let's start by creating a table with a boolean column. We will use the boolean data type to represent whether a product is available or not.
3. Let’s imagine you’re designing a system that stores data about movies, including whether they have been flagged as “recommended” by an editorial team. With the new boolean data type, you can store this as a TRUE or FALSE value instead of relying on numeric or character codes.

In this task, you will:
- Create a MOVIES table with a boolean column.
- Insert rows with boolean values using various literals.
- Query the table to see how boolean values are represented and manipulated.
- Update a MOVIE with a boolean
- Insert a new MOVIE with a boolean using PL/SQL

```
<copy>
drop table if EXISTS product;
DROP TABLE IF EXISTS MOVIES CASCADE CONSTRAINT;
CREATE TABLE product (
product_name VARCHAR2(100),
available BOOLEAN
-- Create MOVIES table with a boolean column
CREATE TABLE MOVIES (
MOVIE_ID NUMBER PRIMARY KEY,
TITLE VARCHAR2(100),
RECOMMENDED BOOLEAN
);
-- Insert sample data using boolean values and accepted boolean literals
INSERT INTO MOVIES VALUES (1, 'The Matrix', TRUE),
(2, 'Jaws', FALSE),
(3, 'Casablanca', 'yes'),
(4, 'Plan 9 From Outer Space', 'no'),
(5, 'Inception', 'on'),
(6, 'Sharknado', 'off'),
(7, 'Interstellar', 1),
(8, 'The Room', 0),
(9, 'Sicario', NULL );
</copy>
```
![Create table](images/im2.png " ")
![create the table for the workshop](images/boolean-1.png " ")
3. Now, let's insert some sample data into the product table, including boolean values for availability.
4. Let’s check that our boolean values have been correctly stored. Notice how different input literals map to TRUE, FALSE, or NULL.
```
<copy>
SELECT movie_id, title, recommended
FROM movies;
</copy>
```
![verify boolean values](images/boolean-2.png " ")
5. Now let’s filter movies based on their boolean values. Suppose we want to find all movies that have been recommended (TRUE).
```
<copy>
INSERT INTO product (product_name, available)
VALUES
('Laptop', TRUE),
('Smartphone', FALSE);
SELECT movie_id, title
FROM movies
WHERE recommended = TRUE;
</copy>
```
![insert into table](images/im3.png " ")
![filter on boolean values](images/boolean-3.png " ")
## Task 2: Working with Boolean Data
6. You can also perform logical operations directly on boolean columns. For example, let’s assume we consider a movie “highly recommended” if it’s currently recommended, and we want to verify this by applying logical conditions.
1. Let's run some queries to retrieve information based on boolean conditions.
- Select all available products
- Select all unavailable products
This is being used here just as a teaching example to show the direct handling of boolean values within your SQL statements. In a practical scenario, you wouldn’t typically add AND TRUE since it doesn’t change the logic.
```
<copy>
SELECT * FROM product WHERE available = TRUE;
SELECT * FROM product WHERE available = FALSE;
-- Select movies where recommended AND TRUE is still TRUE
SELECT movie_id, title
FROM movies
WHERE recommended AND TRUE;
</copy>
```
![select from the table](images/im4.png " ")
![logical AND](images/boolean-4.png " ")
Similarly, you can check which movies are not recommended:
```
<copy>
SELECT movie_id, title
FROM movies
WHERE NOT recommended;
</copy>
```
![logical NOT](images/boolean-5.png " ")
2. You can also update boolean values just like any other data type. Imagine we got a new shipment of smartphones and want to update the availability.
7. If you want to identify movies that are either recommended or have a title starting with 'I', you can combine boolean logic with standard SQL conditions:
```
<copy>
UPDATE product SET available = TRUE WHERE product_name = 'Smartphone';
SELECT movie_id, title
FROM movies
WHERE recommended OR title LIKE 'I%';
</copy>
```
![update the table](images/im5.png " ")
![logical OR with conditions](images/boolean-6.png " ")
8. You can perform DDL against the table just as you'd expect. Here, update the movie jaws so it is now recommended:
```
<copy>
SELECT title, recommended from movies where movie_id = 2;
UPDATE movies
SET recommended = true
WHERE movie_id = 2;
2. Additionally, let's modify with PL/SQL and the boolean data type. Insert a TV into the `product` table with a predefined boolean value of true.
SELECT title, recommended from movies where movie_id = 2;
</copy>
```
![logical OR with conditions](images/boolean-7.png " ")
9. Additionally, let's modify with PL/SQL and the boolean data type. Add a new movie:
```
<copy>
DECLARE
l_product_name VARCHAR2(100) := 'TV';
l_movie_id NUMBER := 10;
l_movie_name VARCHAR2(100) := 'Surfs Up';
l_recommended BOOLEAN := TRUE;
BEGIN
INSERT INTO product (product_name, available)
VALUES (l_product_name, TRUE);
INSERT INTO movies (movie_id, title, recommended)
VALUES (l_movie_id, l_movie_name, l_recommended);
COMMIT;
COMMIT;
END;
/
</copy>
```
![Run PL/SQL](images/im5.png " ")
![logical OR with conditions](images/boolean-8.png " ")
3. Now if we select from our product table, we can see the additional product with the availability of 1 being true.
10. You can check the recommended movies now:
```
<copy>
select * from product;
SELECT movie_id, title
FROM movies
WHERE recommended = TRUE;
</copy>
```
![Run PL/SQL](images/im6.png " ")
4. In this lab, you gained a very small bit of hands-on experience with the boolean data type in Oracle Database 23ai. You learned how to define boolean columns, insert boolean values, perform boolean operations in SQL queries, and utilize boolean types in PL/SQL. Understanding boolean functionality is helpful for effective data manipulation and decision-making in database systems.
![filter on boolean values](images/boolean-9.png " ")
Feel free to continue experimenting with boolean values or explore other features of Oracle Database 23ai.
5. We can clean up from the lab by dropping our tables.
11. As with any lab, you can clean up by dropping the table when you’re done.
```
<copy>
DROP TABLE product CASCADE CONSTRAINTS;
DROP TABLE IF EXISTS MOVIES CASCADE CONSTRAINT;
</copy>
```
You may now **proceed to the next lab**
## Learn More
* [Introducing Oracle Database 23ai Boolean Data Type](https://medium.com/oracledevs/boolean-data-type-in-oracle-database-23ai-b9ae541c697f)
Expand All @@ -129,4 +179,4 @@ You may now **proceed to the next lab**
## Acknowledgements
* **Author** - Killian Lynch, Database Product Management
* **Contributors** - Dom Giles, Distinguished Database Product Manager
* **Last Updated By/Date** - Killian Lynch, April 2024
* **Last Updated By/Date** - Killian Lynch, December 2024
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading
Sorry, something went wrong. Reload?
Sorry, we cannot display this file.
Sorry, this file is invalid so it cannot be displayed.
Loading

0 comments on commit 0f4d1f1

Please sign in to comment.