MacLochlainns Weblog

Michael McLaughlin's Technical Blog

Site Admin

Archive for the ‘Linux’ Category

Postgres Foreign Keys

without comments

Just sorting out how to query the information_schema to discover the magic for a query of a table’s foreign key constraints. This query works to return the foreign key constraints:

SELECT   conrelid::regclass::text AS table_from
,        conname AS foreign_key
,        pg_get_constraintdef(oid)
FROM     pg_constraint
WHERE    contype = 'f'
AND      connamespace = 'public'::regnamespace 
AND      conrelid::regclass::text = 'rental_item'
ORDER BY conrelid::regclass::text
,        conname;

It returns the following for the rental_item table:

 table_from  |   foreign_key    |                           pg_get_constraintdef                            
-------------+------------------+---------------------------------------------------------------------------
 rental_item | fk_rental_item_1 | FOREIGN KEY (rental_id) REFERENCES rental(rental_id)
 rental_item | fk_rental_item_2 | FOREIGN KEY (item_id) REFERENCES item(item_id)
 rental_item | fk_rental_item_3 | FOREIGN KEY (created_by) REFERENCES system_user(system_user_id)
 rental_item | fk_rental_item_4 | FOREIGN KEY (last_updated_by) REFERENCES system_user(system_user_id)
 rental_item | fk_rental_item_5 | FOREIGN KEY (rental_item_type) REFERENCES common_lookup(common_lookup_id)
(5 rows)

As always, I post these tidbit for others to discover and use with less pain.

Written by maclochlainn

November 6th, 2019 at 12:31 am

Postgres Overloaded Routines

without comments

Earlier I showed how to write an anonymous block in PostgreSQL PL/pgSQL to drop routines, like functions and procedures. However, it would only work when they’re not overloaded functions or procedures. The following lets you drop all routines, including overloaded functions and procedures. Overloaded procedures are those that share the same name but have different parameter lists.

Before you can test the anonymous block, you need to create a set of overloaded functions or procedures. You can create a set of overloaded hello procedures with the following syntax:

CREATE FUNCTION hello()
RETURNS text AS
$$
DECLARE
  output  VARCHAR;
BEGIN
  SELECT 'Hello World!' INTO output;
  RETURN output;
END
$$ LANGUAGE plpgsql;
 
CREATE FUNCTION hello(whom text)
RETURNS text AS
$$
DECLARE
  output  VARCHAR;
BEGIN
  SELECT CONCAT('Hello ',whom,'!') INTO output;
  RETURN output;
END
$$ LANGUAGE plpgsql;
 
CREATE FUNCTION hello(id int, whom text)
RETURNS text AS
$$
DECLARE
  output  VARCHAR;
BEGIN
  SELECT CONCAT('[',id,'] Hello ',whom,'!') INTO output;
  RETURN output;
END
$$ LANGUAGE plpgsql;

You can test the overloaded hello function, like so from the videodb schema:

videodb=> SELECT hello();
    hello     
--------------
 Hello World!
(1 ROW)
 
videodb=> SELECT hello('Captain Marvel');
         hello         
-----------------------
 Hello Captain Marvel!
(1 ROW)
 
videodb=> SELECT hello(1,'Captain America');
           hello            
----------------------------
 [1] Hello Captain America!
(1 ROW)

Then, you can query the information_schema to verify that you’ve created a set of overloaded procedures with the following query:

SELECT   proc.specific_schema AS procedure_schema
,        proc.specific_name
,        proc.routine_name AS procedure_name
,        proc.external_language
,        args.parameter_name
,        args.parameter_mode
,        args.data_type
FROM     information_schema.routines proc left join information_schema.parameters args
ON       proc.specific_schema = args.specific_schema
AND      proc.specific_name = args.specific_name
WHERE    proc.routine_schema NOT IN ('pg_catalog', 'information_schema')
AND      proc.routine_type IN ('FUNCTION','PROCEDURE')
ORDER BY procedure_schema
,        specific_name
,        procedure_name
,        args.ordinal_position;

It should return the following:

 procedure_schema | specific_name | procedure_name | external_language | parameter_name | parameter_mode | data_type 
------------------+---------------+----------------+-------------------+----------------+----------------+-----------
 public           | hello_35451   | hello          | PLPGSQL           |                |                | 
 public           | hello_35452   | hello          | PLPGSQL           | whom           | IN             | text
 public           | hello_35453   | hello          | PLPGSQL           | id             | IN             | integer
 public           | hello_35453   | hello          | PLPGSQL           | whom           | IN             | text
(4 rows)

The set session command maps the videodb catalog for the following anonymous block program.

SET SESSION "videodb.catalog_name" = 'videodb';

The following anonymous block lets you get rid of any ordinary or overloaded function and procedure:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
DO $$
DECLARE
  /* Declare an indefinite length string for SQL statement. */
  sql  VARCHAR;
 
  /* Declare variables to manage cursor return values. */
  row  RECORD;
  arg  VARCHAR;
 
  /* Declare parameter list. */
  list VARCHAR;
 
  /* Declare a routine cursor. */
  routine_cursor CURSOR FOR
    SELECT routine_name
    ,      specific_name
    ,      routine_type
    FROM   information_schema.routines
    WHERE  specific_catalog = current_setting('videodb.catalog_name')
    AND    routine_schema = 'public';
 
  /* Declare a parameter cursor. */
  parameter_cursor CURSOR (cv_specific_name varchar) FOR
    SELECT args.data_type
    FROM   information_schema.parameters args
    WHERE  args.specific_schema = 'public'
    AND    args.specific_name = cv_specific_name;
 
BEGIN
  /* Open the cursor. */
  OPEN routine_cursor;
  <<row_loop>>
  LOOP
    /* Fetch table names. */
    FETCH routine_cursor INTO row;
 
    /* Exit when no more records are found. */
    EXIT row_loop WHEN NOT FOUND;
 
    /* Initialize parameter list. */
    list := '(';
 
    /* Open the parameter cursor. */
    OPEN parameter_cursor(row.specific_name::varchar);
    <<parameter_loop>>
    LOOP
      FETCH parameter_cursor INTO arg;
 
      /* Exit the parameter loop. */
      EXIT parameter_loop WHEN NOT FOUND;
 
      /* Add parameter and delimit more than one parameter with a comma. */
      IF LENGTH(list) > 1 THEN
        list := CONCAT(list,',',arg);
      ELSE
        list := CONCAT(list,arg);
      END IF;
    END LOOP;
 
    /* Close the parameter list. */
    list := CONCAT(list,')');
 
    /* Close the parameter cursor. */
    CLOSE parameter_cursor;
 
    /* Concatenate together a DDL to drop the table with prejudice. */
    sql := 'DROP '||row.routine_type||' IF EXISTS '||row.routine_name||list;
 
    /* Execute the DDL statement. */
    EXECUTE sql;
  END LOOP;
 
  /* Close the routine_cursor. */
  CLOSE routine_cursor;
END;
$$;

Now, you possess the magic to automate cleaning up your schema when you combine this with my earlier post on dynamically dropping tables, sequences, and triggers.

Written by maclochlainn

November 5th, 2019 at 12:11 am

DBeaver for PostgreSQL

without comments

I’m migrating my database classes from the Oracle database to the PostgreSQL database. Using the Oracle Express Edition has always required a virtualized image because students use Windows and Mac OS. Also, the university doesn’t like my use of a virtualized image. Virtualization imposes incremental cost on students to have high end laptops.

The available Docker images don’t typically support the Oracle Express Edition. That means there are licensing implications tied to Oracle.

As a committee, we decided to use PostgreSQL as our new database platform. We opted to use PostgreSQL over MySQL because it supports arrays and stored procedures. PostgreSQL PL/pgSQL are a solid implementation of stored procedures. While MySQL supports a stored procedure language, it effectively discourages using it.

We use sqlplus, mysql, or psql Command-Line Interface (CLI) as the primary interface. That’s because CLI supports production-oriented deployment and DevOps practices. The Open Source DBeaver project provides a clean native GUI management console for PostgreSQL. DBeaver also supports other databases, which pgAdmin doesn’t.

You click the Download button from the DBeaver home page. It support Windows, Mac OS, and Linux distributions. I downloaded the Linux RPM package to my Downloads directory. You can run the RPM with the following syntax:

rpm -ivh dbeaver-ce-6.2.3-stable.x86_64.rpm

It doesn’t check for dependencies. The installation is quick. You can verify that it’s installed with the following command:

which dbeaver

It installs here:

/usr/bin/dbeaver

If you failed to install the PostgreSQL JAR file, you’ll see the following error message:

It will look like the following on Linux:

You should have a user in the pg_hba.conf file, like the following:

host    all             all             127.0.0.1/32            trust

As always, I hope this helps those solving problems.

Written by maclochlainn

November 3rd, 2019 at 5:06 pm

Java and Postgres

without comments

I wanted to get Java working with PostgreSQL to test some GUI interfaces on Linux. Figuring out the necessary JAR file for the JDBC was my first hurdle. I found it was postgreSQL-42-2.5.jar file.

You can download it with the following command line:

wget https://jdbc.postgresql.org/download/postgresql-42.2.5.jar

I downloaded it to a Java directory off the home/student directory. Then, I added the following CLASSPATH to local java.env environment file.

#!/usr/bin/bash
 
# Set the Java CLASSPATH environment variable to include the JDBC jar file.
export set CLASSPATH=/home/student/Java/postgresql-42.2.5.jar:.

I sourced the postgresql-42.2.5.jar file and I wrote the following JavaTest.java program:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
/* Import classes. */
import java.sql.Connection;
import java.sql.DriverManager;
import java.sql.ResultSet;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.logging.Level;
import java.util.logging.Logger;
 
public class JavaTest { 
  public static void main(String[] args) {
    /* Set default strings for the connection. */
    String url = "jdbc:postgresql://localhost:5432/videodb";
    String user = "student";
    String password = "student";
 
    /* Try the connection and statement. */
    try {
      Connection conn = DriverManager.getConnection(url, user, password);
      Statement st = conn.createStatement();
      ResultSet rs = st.executeQuery("SELECT VERSION()");
 
      if (rs.next()) {
        System.out.println(rs.getString(1));
      }
 
      /* Close the result set and statement. */
      rs.close();
      st.close();
    }
    catch (SQLException e) {
      Logger logger = Logger.getLogger(JavaTest.class.getName());
      logger.log(Level.SEVERE, e.getMessage(), e);
    }
  }
}

I compiled the JavaTest.java program and tested it. It failed with the following error:

FATAL: Ident authentication failed for user - Unable to connect to PostgreSQL

The failure occurred because I hadn’t allowed the connection in PostgreSQL’s pg_hba.conf file. I changed the following line in my pg_hba.conf file:

host    all             all             127.0.0.1/32            ident

to

host    all             all             127.0.0.1/32            trust

Then, I restarted the postgresql-11 service, like this:

systemctl restart postgresql-11.service

The JavaTest program ran successfully and returned:

PostgreSQL 11.5 on x86_64-pc-linux-gnu, compiled by gcc (GCC) 9.1.1 20190503 (Red Hat 9.1.1-1), 64-bit

You can extend the logic to output a comma-separated value file by leveraging the JDBC help page, like this:

/* Import classes. */
import java.sql.Connection;
import java.sql.DriverManager;
import java.sql.ResultSet;
import java.sql.ResultSetMetaData;
import java.sql.SQLException;
import java.sql.Statement;
import java.util.logging.Level;
import java.util.logging.Logger;
 
/* Create class withonly a static method for runtime testing. */
public class JavaReturnSet { 
  public static void main(String[] args) {
    /* Set default strings for the connection. */
    String url = "jdbc:postgresql://localhost:5432/videodb";
    String user = "student";
    String password = "student";
 
    /* Try the connection and statement. */
    try {
      /* Set connection, statement, and result set. */
      Connection conn = DriverManager.getConnection(url, user, password);
      Statement st = conn.createStatement();
 
      /* Use the + to concatenate lines for query clarity. */
      ResultSet rs = st.executeQuery("SELECT m.account_number\n" +
                                     ",      CONCAT(c.last_name,', ',c.first_name)\n" +
                                     "FROM   member m JOIN contact c\n" +
                                     "ON     m.member_id = c.member_id");
 
      /* Get query metadata for subsequent management of results. */
      ResultSetMetaData rsmd = rs.getMetaData();
      String line;
 
      while (rs.next()) {
        /* Initialize the line output for each row. */
        line = "";
 
        /* Process the columns. */
        for (int i = 0; i < rsmd.getColumnCount(); i++) {
          if (rsmd.getColumnType(i + 1) == 12) {
            line = line + "\"" + rs.getString(i + 1) + "\"";
          }
          else {
            line = line + rs.getInt(i + 1);
          }
 
          /* Put a comma between output columns. */
          if (i < rsmd.getColumnCount() - 1) {
            line = line + ",";
          }
        }
        System.out.println(line);
      }
 
      /* Close the result set and statement. */
      rs.close();
      st.close();
    }
    catch (SQLException e) {
      Logger logger = Logger.getLogger(JavaReturnSet.class.getName());
      logger.log(Level.SEVERE, e.getMessage(), e);
    }
  }
}

As always, I hope this helps those looking for a clean solution.

Written by maclochlainn

November 2nd, 2019 at 11:46 pm

Postgres Drop Structures

with one comment

While building my PostgreSQL environment for the class, I had to write a couple utilities. They do the following:

  1. Drops all the tables from a schema.
  2. Drops all the sequences from a schema that aren’t tied to an _id column with a SERIAL data type.
  3. Drops all the functions and procedures (qualified as routines) from a schema.
  4. Drops all the triggers from a schema.

The following gives you the code for all four files: drop_tables.sql, drop_sequences.sql, drop_routines.sql, and drop_triggers.sql.

  • The drop_tables.sql Script:
  • /* Verify all tables present. */
    SELECT table_name
    FROM   information_schema.tables
    WHERE  table_catalog = current_setting('videodb.catalog_name')
    AND    table_schema = 'public';
     
    DO $$
    DECLARE
      /* Declare an indefinite length string and record variable. */
      sql  VARCHAR;
      row  RECORD;
     
      /* Declare a cursor. */
      table_cursor CURSOR FOR
        SELECT table_name
        FROM   information_schema.tables
        WHERE  table_catalog = current_setting('videodb.catalog_name')
        AND    table_schema = 'public';
    BEGIN
      /* Open the cursor. */
      OPEN table_cursor;
      LOOP
        /* Fetch table names. */
        FETCH table_cursor INTO row;
     
        /* Exit when no more records are found. */
        EXIT WHEN NOT FOUND;
     
        /* Concatenate together a DDL to drop the table with prejudice. */
        sql := 'DROP TABLE IF EXISTS '||row.table_name||' CASCADE';
     
        /* Execute the DDL statement. */
        EXECUTE sql;
      END LOOP;
     
      /* Close the cursor. */
      CLOSE table_cursor;
    END;
    $$;
     
    /* Verify all tables are dropped. */
    SELECT table_name
    FROM   information_schema.tables
    WHERE  table_catalog = current_setting('videodb.catalog_name')
    AND    table_schema = 'public';

  • The drop_sequences.sql script:
  • /* Verify all tables present. */
    SELECT sequence_name
    FROM   information_schema.sequences
    WHERE  sequence_catalog = current_setting('videodb.catalog_name')
    AND    sequence_schema = 'public';
     
    DO $$
    DECLARE
      /* Declare an indefinite length string and record variable. */
      sql  VARCHAR;
      row  RECORD;
     
      /* Declare a cursor. */
      sequence_cursor CURSOR FOR
        SELECT sequence_name
        FROM   information_schema.sequences
        WHERE  sequence_catalog = current_setting('videodb.catalog_name')
        AND    sequence_schema = 'public';
    BEGIN
      /* Open the cursor. */
      OPEN sequence_cursor;
      LOOP
        /* Fetch table names. */
        FETCH sequence_cursor INTO row;
     
        /* Exit when no more records are found. */
        EXIT WHEN NOT FOUND;
     
        /* Concatenate together a DDL to drop the table with prejudice. */
        sql := 'DROP SEQUENCE IF EXISTS '||row.sequence_name;
     
        /* Execute the DDL statement. */
        EXECUTE sql;
      END LOOP;
     
      /* Close the cursor. */
      CLOSE sequence_cursor;
    END;
    $$;
     
    /* Verify all tables are dropped. */
    SELECT sequence_name
    FROM   information_schema.sequences
    WHERE  sequence_catalog = current_setting('videodb.catalog_name')
    AND    sequence_schema = 'public';

  • The drop_routines.sql script:
  • /* Verify all tables present. */
    SELECT routine_name
    ,      routine_type
    FROM   information_schema.routines
    WHERE  specific_catalog = current_setting('videodb.catalog_name')
    AND    specific_schema = 'public';
     
    DO $$
    DECLARE
      /* Declare an indefinite length string and record variable. */
      sql  VARCHAR;
      row  RECORD;
     
      /* Declare a cursor. */
      routine_cursor CURSOR FOR
        SELECT routine_name
        ,      routine_type
        FROM   information_schema.routines
        WHERE  specific_catalog = current_setting('videodb.catalog_name')
        AND    routine_schema = 'public';
    BEGIN
      /* Open the cursor. */
      OPEN routine_cursor;
      LOOP
        /* Fetch table names. */
        FETCH routine_cursor INTO row;
     
        /* Exit when no more records are found. */
        EXIT WHEN NOT FOUND;
     
        /* Concatenate together a DDL to drop the table with prejudice. */
        sql := 'DROP '||row.routine_type||' IF EXISTS '||row.routine_name;
     
        /* Execute the DDL statement. */
        EXECUTE sql;
      END LOOP;
     
      /* Close the cursor. */
      CLOSE routine_cursor;
    END;
    $$;
     
    /* Verify all tables are dropped. */
    SELECT routine_name
    ,      routine_type
    FROM   information_schema.routines
    WHERE  specific_catalog = 'videodb'
    AND    specific_schema = 'public';

  • The drop_triggers.sql script:
  • /* Verify all tables present. */
    SELECT trigger_name
    FROM   information_schema.triggers
    WHERE  trigger_catalog = current_setting('videodb.catalog_name')
    AND    trigger_schema = 'public';
     
    DO $$
    DECLARE
      /* Declare an indefinite length string and record variable. */
      sql  VARCHAR;
      row  RECORD;
     
      /* Declare a cursor. */
      trigger_cursor CURSOR FOR
        SELECT trigger_name
        FROM   information_schema.triggers
        WHERE  trigger_catalog = current_setting('videodb.catalog_name')
        AND    trigger_schema = 'public';
    BEGIN
      /* Open the cursor. */
      OPEN trigger_cursor;
      LOOP
        /* Fetch table names. */
        FETCH trigger_cursor INTO row;
     
        /* Exit when no more records are found. */
        EXIT WHEN NOT FOUND;
     
        /* Concatenate together a DDL to drop the table with prejudice. */
        sql := 'DROP TRIGGER IF EXISTS '||row.trigger_name;
     
        /* Execute the DDL statement. */
        EXECUTE sql;
      END LOOP;
     
      /* Close the cursor. */
      CLOSE trigger_cursor;
    END;
    $$;
     
    /* Verify all tables are dropped. */
    SELECT trigger_name
    FROM   information_schema.triggers
    WHERE  trigger_catalog = current_setting('videodb.catalog_name')
    AND    trigger_schema = 'public';

You can create a cleanup_catalog.sql script to call all four in sequence, like the following:

\i /home/student/Data/cit225/postgres/lib/utility/drop_tables.sql
\i /home/student/Data/cit225/postgres/lib/utility/drop_sequences.sql
\i /home/student/Data/cit225/postgres/lib/utility/drop_routines.sql
\i /home/student/Data/cit225/postgres/lib/utility/drop_triggers.sql

The nice thing about this approach is that you won’t see any notices when tables, sequences, routines, or triggers aren’t found. It’s a clean approach to cleaning the schema for a testing environment.

Written by maclochlainn

October 27th, 2019 at 3:58 pm

Postgres SQL Nuance

without comments

I ran across an interesting nuance between Oracle and Postgres with the double-pipe operator. I found that the following query failed to cross port from Oracle to Postgres:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
COL account_number  FORMAT A10  HEADING "Account|Number"
COL full_name       FORMAT A16  HEADING "Name|(Last, First MI)"
COL city            FORMAT A12  HEADING "City"
COL state_province  FORMAT A10  HEADING "State"
COL telephone       FORMAT A18  HEADING "Telephone"
SELECT   m.account_number
,        c.last_name || ', ' || c.first_name
||       CASE
           WHEN c.middle_name IS NOT NULL THEN ' ' || c.middle_name
         END AS full_name
,        a.city
,        a.state_province
,        t.country_code || '-(' || t.area_code || ') ' || t.telephone_number AS telephone
FROM     member m INNER JOIN contact c ON m.member_id = c.member_id INNER JOIN
         address a ON c.contact_id = a.contact_id INNER JOIN
         street_address sa ON a.address_id = sa.address_id INNER JOIN
         telephone t ON c.contact_id = t.contact_id AND a.address_id = t.address_id
WHERE    c.last_name = 'Winn';

In Oracle, a CASE statement ignores the null of a missing ELSE clause between lines 4 and 5. Oracle assumes a null value is an empty string when concatenated to a string with the double-piped concatenation operator. Oracle’s implementation differs from the ANSI standard and is non-compliant.

It would display the following thanks to the SQL reporting features that don’t exist in other Command-Line Interface (CLI) implementations, like mysql, psql, sqlcmd, or cql:

Account    Name
Number     (Last, First MI) City         State      Telephone
---------- ---------------- ------------ ---------- ------------------
B293-71445 Winn, Randi      San Jose     CA         001-(408) 111-1111
B293-71445 Winn, Brian      San Jose     CA         001-(408) 111-1111

However, it fails in Postgres without a notice, warning, or error. Postgres simply returns a null string for the missing ELSE clause and follows the rule that any string concatenated against a null is a null. That means it retunes a null value for the full_name column above. The Postgres behavior is the ANSI standard behavior. After years of working with Oracle it was interesting to have this pointed out while porting a query.

You can fix the statement in Postgres by adding an explicit ELSE clause on a new line 5 that appends an empty string, like this:

1
2
3
4
5
6
7
8
9
10
11
12
13
14
SELECT   m.account_number
,        c.last_name || ', ' || c.first_name
||       CASE
           WHEN c.middle_name IS NOT NULL THEN ' ' || c.middle_name
           ELSE ''
         END AS full_name
,        a.city
,        a.state_province
,        t.country_code || '-(' || t.area_code || ') ' || t.telephone_number AS telephone
FROM     member m INNER JOIN contact c ON m.member_id = c.member_id INNER JOIN
         address a ON c.contact_id = a.contact_id INNER JOIN
         street_address sa ON a.address_id = sa.address_id INNER JOIN
         telephone t ON c.contact_id = t.contact_id AND a.address_id = t.address_id
WHERE    c.last_name = 'Winn';

It would display:

 account_number |  full_name  |   city   | state_province |     telephone      
----------------+-------------+----------+----------------+--------------------
 B293-71445     | Winn, Randi | San Jose | CA             | 001-(408) 111-1111
 B293-71445     | Winn, Brian | San Jose | CA             | 001-(408) 111-1111
(2 rows)

As always, I hope this helps those looking to solve a problem.

Written by maclochlainn

October 12th, 2019 at 1:20 pm

Postgres Foreign Constraints

without comments

You can’t disable a foreign key constraint in Postgres, like you can do in Oracle. However, you can remove the foreign key constraint from a column and then re-add it to the column.

Here’s a quick test case in five steps:

  1. Drop the big and little table if they exists. The first drop statement requires a cascade because there is a dependent little table that holds a foreign key constraint against the primary key column of the big table. The second drop statement does not require the cascade keyword because there is not a dependent foreign key constraint.

    DROP TABLE IF EXISTS big CASCADE;
    DROP TABLE IF EXISTS little;

  2. Create the big and little tables:

    -- Create the big table.
    CREATE TABLE big
    ( big_id     SERIAL
    , big_text   VARCHAR(20) NOT NULL
    , CONSTRAINT pk_little_1 PRIMARY KEY (big_id));
     
    -- Display the big table.
    \d big
     
    -- Create little table.
    CREATE TABLE little
    ( little_id     SERIAL
    , big_id        INTEGER     NOT NULL
    , little_text   VARCHAR(20) NOT NULL
    , CONSTRAINT fk_little_1 FOREIGN KEY (big_id) REFERENCES big (big_id));
     
    -- Display the little table.
    \d little

    If you failed to designate the big_id column as a primary key constrained, Postgres will raise the following exception:

    ERROR:  there IS no UNIQUE CONSTRAINT matching given KEYS FOR referenced TABLE "big"

  3. Insert a non-compliant row in the little table. An insert statement into the little table with a value for the foreign key column that does not exist in the big_id column of the big table would fail with the following error:

    ERROR:  INSERT OR UPDATE ON TABLE "little" violates FOREIGN KEY CONSTRAINT "fk_little_1"
    DETAIL:  KEY (big_id)=(2) IS NOT present IN TABLE "big".

    Re-enabling the foreign key constraint, the insert statement succeeds after you first insert a new row into the big table with the foreign key value for the little table as its primary key. The following two insert statements add a row to both the big and little table:

    -- Insert into a big table.
    INSERT INTO big
    (big_text)
    VALUES
    ('Cat in the Hat 2');
     
    -- Insert into a little table.
    INSERT INTO little
    (big_id
    ,little_text)
    VALUES
    ( 2
    ,'Thing 3');

    Then, you can query it like this:

    SELECT *
    FROM   big b JOIN little l ON b.big_id = l.big_id;

     big_id |     big_text     | little_id | big_id | little_text 
    --------+------------------+-----------+--------+-------------
          1 | Cat IN the Hat 1 |         1 |      1 | Thing 1
          1 | Cat IN the Hat 1 |         2 |      1 | Thing 2
          2 | Cat IN the Hat 2 |         3 |      2 | Thing 3
    (3 ROWS)

  4. You can drop a foreign key constraint with the following syntax:

    ALTER TABLE little DROP CONSTRAINT fk_little_1;

  5. You can add a foreign key constraint with the following syntax:

    ALTER TABLE little ADD CONSTRAINT fk_little_1 FOREIGN KEY (big_id) REFERENCES big (big_id);

As always, I hope this helps you solve problems.

Written by maclochlainn

October 8th, 2019 at 8:49 pm

Postgres Remove Constraints

without comments

You can’t disable a not null constraint in Postgres, like you can do in Oracle. However, you can remove the not null constraint from a column and then re-add it to the column.

Here’s a quick test case in four steps:

  1. Drop a demo table if it exists:

    DROP TABLE IF EXISTS demo;

  2. Create a demo table if it exists:

    CREATE TABLE demo
    ( demo_id    SERIAL
    , demo_text  VARCHAR(20) NOT NULL );

  3. Insert a compliant row in the demo table if it exists:

    INSERT INTO demo
    (demo_text)
    VALUES
    ('Thing 1');

    Attempt to insert another row with a null value in the demo_text column:

    INSERT INTO demo
    (demo_text)
    VALUES
    (NULL);

    It raises the following error:

    INSERT 0 1
    psql:remove_not_null.sql:22: ERROR:  NULL VALUE IN COLUMN "demo_text" violates not-NULL CONSTRAINT
    DETAIL:  Failing ROW contains (2, NULL).

  4. You can drop the not null constraint from the demo_text column:

    ALTER TABLE demo ALTER COLUMN demo_text DROP NOT NULL;

    You can now successfully insert a row with a demo_text column value of null. After you have performed your table maintenance you can add the not null constraint back on to the demo_text column.

    You need to update the row with a null value in the demo_text column with a valid value before you re-add the not null constraint. The following shows an update statement that replaces the null value with a text string:

    UPDATE demo
    SET    demo_text = 'Thing 2'
    WHERE  demo_text IS NULL;

    Now, you can change the demo_text column back to a not null constrained column with the following syntax.

    ALTER TABLE demo ALTER COLUMN demo_text SET NOT NULL;

  5. While you can not defer the constraint, removing it and adding it back works well.

Written by maclochlainn

October 8th, 2019 at 12:26 am

Postgres Check Constraints

without comments

The Postgres 11 database documentation says that it supports naming constraints. While you can create a table with named constraints inside the CREATE TABLE statement, the names are not assigned to the not null check constraint.

Here’s a quick test case in three steps:

  1. Drop a demo table if it exists:

    DROP TABLE IF EXISTS demo;

  2. Drop a demo table if it exists:

    CREATE TABLE demo
    ( demo_id    SERIAL
    , demo_text  VARCHAR(20) CONSTRAINT nn_demo_1 NOT NULL );

  3. Create a demo table if it exists:

    SELECT substr(check_clause,1,strpos(check_clause,' ')-1) AS check_column
    ,      constraint_name
    FROM   information_schema.check_constraints
    WHERE  check_clause LIKE 'demo_text%';

    You should see the following output with a parsed check_column name and the system generated check constraint name rather than the nn_demo_1 constraint name:

     check_column |    constraint_name    
    --------------+-----------------------
     demo_text    | 2200_18896_2_not_null
    (1 row)

  4. On the bright side, you can name primary key and foreign key constraints.

Written by maclochlainn

October 7th, 2019 at 10:35 pm

Python-Postgres Query

without comments

As I committed to a student, here are sample programs for writing a Python query against the Postgres 11 database. The first one returns rows or tuples. The latter formats the text returned as columns.

If you’re one of many looking for the key psycopg2 driver library, you can find it in most distro repositories as: python3-psycopg2. You can use dnf or yum to install it separately or you can install pgadmin4, which includes the psycopg2 library.

The first example returns the entire row from a new_hire table with two rows:

import psycopg2
 
try:
  # Open a connection to the database.
  connection = psycopg2.connect( user="student"
                               , password="student"
                               , port="5432"
                               , dbname="videodb")
 
  # Open a cursor.
  cursor = connection.cursor()
 
  # Assign a static query.
  query = "SELECT * FROM new_hire"
 
  # Parse and execute the query.
  cursor.execute(query)
 
  # Fetch all rows from a table.
  records = cursor.fetchall()
 
  # Read through and print the rows as tuples.
  for row in range(0, len(records)):
    print(records[row]) 
 
except (Exception, psycopg2.Error) as error :
  print("Error while fetching data from PostgreSQL", error)
 
finally:
  # Close the database connection.
  if (connection):
    cursor.close()
    connection.close()

The first example returns the rows as tuples, which is probably desired if you want to consume the result in another Python program. Here’s the output retrieved:

(1001, 'Malcolm', 'Jacob', 'Lewis', datetime.date(2018, 2, 14))
(1002, 'Henry', None, 'Chabot', datetime.date(1990, 7, 31))

The second one returns the rows and formats the columns into output for a csv style file:

import psycopg2
 
try:
  # Open a connection to the database.
  connection = psycopg2.connect( user="student"
                               , password="student"
                               , port="5432"
                               , dbname="videodb")
 
  # Open a cursor.
  cursor = connection.cursor()
 
  # Assign a static query.
  query = "SELECT * FROM new_hire"
 
  # Parse and execute the query.
  cursor.execute(query)
 
  # Read through and print the formatted columns of each row.
  for (new_hire_id, first_name, middle_name, last_name, hire_date) in cursor:
    if (isinstance(middle_name,type(None))):
      print("{},'{} {}','{:%d-%b-%Y}'".format(new_hire_id, first_name, last_name, hire_date))
    else:
      print("{},'{} {} {}','{:%d-%b-%Y}'".format(new_hire_id, first_name, middle_name, last_name, hire_date))
 
except (Exception, psycopg2.Error) as error :
  print("Error while fetching data from PostgreSQL", error)
 
finally:
  # Close the database connection.
  if (connection):
    cursor.close()
    connection.close()

The second one returns the rows and formatted columns for a csv style file:

1001,'Malcolm Jacob Lewis','14-Feb-2018'
1002,'Henry Chabot','31-Jul-1990'

As always, I hope these help those looking for a starting place with Python and Postgres.

Written by maclochlainn

September 23rd, 2019 at 1:23 am