Skip to content

Contact sales

By filling out this form and clicking submit, you acknowledge our privacy policy.
  • Labs icon Lab
  • A Cloud Guru
Google Cloud Platform icon
Labs

Working With Data in PostgreSQL

PostgreSQL is the world's most advanced open source database. Its stability, functionality, and extensibility make it a primary choice for an RDBMS solution. In this hands-on lab scenario, you are the DBA for Awesome Company. You have built a PostgreSQL database backend to facilitate the development of a new web application. You will utilize the SQL language to carry out a number of tasks that the development group has requested for the database. Performing the tasks of this lab will help you become familiar with essential SQL language tasks in PostgreSQL. This includes creating objects, inserting and changing data, as well as retrieving data.

Google Cloud Platform icon
Labs

Path Info

Level
Clock icon Intermediate
Duration
Clock icon 30m
Published
Clock icon Mar 20, 2020

Contact sales

By filling out this form and clicking submit, you acknowledge our privacy policy.

Table of Contents

  1. Challenge

    Create the "acweb" Database and Restore Its Backup

    • Change to the postgres user:
      sudo su - postgres
      
    • Create the database to be restored:
      createdb acweb
      
    • Download the backup from GitHub:
      wget https://github.com/linuxacademy/content-postgresql-deepdive/raw/master/acweb/acweb.tar
      
    • Use pg_restore to restore the backup:
      pg_restore --dbname=acweb --verbose /var/lib/pgsql/acweb.tar
      
    • Launch psql and verify the data is present:
      psql
      
      • List the databases with \l.
      • Connect to acweb:
        \c acweb
        
      • Get a count for the payment table:
        SELECT COUNT(*) FROM sales.payment;
        
  2. Challenge

    Create the Table "payment_audit"

    • Use the following query to create the table:
      CREATE TABLE payment_audit (
         payment_id INTEGER,
         customer_id INTEGER,
         amount numeric(6,2),
         payment_date timestamp without time zone NOT NULL,
         username VARCHAR(20),
         delete_date TIMESTAMP
      );
      
  3. Challenge

    Create the Trigger and Function "audit_payment_deletes"

    • Use the following query to create the needed function:
      CREATE FUNCTION audit_payment_deletes() RETURNS trigger AS $$
         BEGIN
            INSERT INTO payment_audit VALUES((OLD).*, current_user, current_timestamp);
            RETURN OLD;
         END;
      $$ LANGUAGE plpgsql;
      
    • Use the following query to create a trigger to call this function:
      CREATE TRIGGER audit_payment_deletes
      BEFORE DELETE ON sales.payment 
      FOR EACH ROW
      EXECUTE PROCEDURE audit_payment_deletes();
      
  4. Challenge

    Create the View "customer_addresses"

    • Use the following query to create the view:
      CREATE VIEW sales.customer_addresses AS
         SELECT c.first_name, c.last_name , a.address, ct.name as city, s.name as state, a.postal_code
         FROM sales.customer c
         LEFT JOIN sales.address a on c.addr_id = a.addr_id
         LEFT JOIN sales.city ct on a.city_id = ct.city_id
         LEFT JOIN sales.state s on ct.state_id = s.state_id;
      
  5. Challenge

    Run Payments From Mick Fowler

    • Query the sales.customer to find the ID for Mick Fowler:
      SELECT * FROM sales.customer
      WHERE first_name = 'Mick'
      AND last_name = 'Fowler';
      
    • Using the ID, insert five payments from Mick as directed in the instructions:
      INSERT INTO sales.payment (customer_id, amount, payment_date)
      VALUES (303, 10, current_timestamp);
      
      INSERT INTO sales.payment (customer_id, amount, payment_date)
      VALUES (303, 20, current_timestamp);
      
      INSERT INTO sales.payment (customer_id, amount, payment_date)
      VALUES (303, 30, current_timestamp);
      
      INSERT INTO sales.payment (customer_id, amount, payment_date)
      VALUES (303, 40, current_timestamp);
      
      INSERT INTO sales.payment (customer_id, amount, payment_date)
      VALUES (303, 50, current_timestamp);
      
    • Change Mick's $30 payment to $15:
      UPDATE sales.payment
      SET amount = 15
      WHERE customer_id = 303
      AND amount = 30;
      
    • Delete all of Mick's payments that are greater than $20:
      DELETE FROM sales.payment
      WHERE customer_id = 303
      AND amount > 20;
      
  6. Challenge

    Verify That Everything Works As Expected

    • Turn on Expanded Display:
      \x
      
    • Query the customer_addresses view to make sure that the first name, last name, address, city, state, and zip code are displayed:
      SELECT * FROM sales.customer_addresses;
      
    • Review the payment_audit table. You should see Mick's payments for $40 and $50 listed:
      SELECT * FROM payment_audit;
      

The Cloud Content team comprises subject matter experts hyper focused on services offered by the leading cloud vendors (AWS, GCP, and Azure), as well as cloud-related technologies such as Linux and DevOps. The team is thrilled to share their knowledge to help you build modern tech solutions from the ground up, secure and optimize your environments, and so much more!

What's a lab?

Hands-on Labs are real environments created by industry experts to help you learn. These environments help you gain knowledge and experience, practice without compromising your system, test without risk, destroy without fear, and let you learn from your mistakes. Hands-on Labs: practice your skills before delivering in the real world.

Provided environment for hands-on practice

We will provide the credentials and environment necessary for you to practice right within your browser.

Guided walkthrough

Follow along with the author’s guided walkthrough and build something new in your provided environment!

Did you know?

On average, you retain 75% more of your learning if you get time for practice.

Start learning by doing today

View Plans