Archive for the ‘psql’ Category
PostgreSQL Creating Schema
The process of creating a schema requires you grant the CREATE ON DATABASE
privilege to the user as the postgres
user. You use the following syntax:
GRANT CREATE ON DATABASE videodb TO student; |
As the student
user, you create the app
schema with the following syntax:
CREATE SCHEMA app; |
Then, you can query the result as follows:
SELECT * FROM pg_catalog.pg_namespace ORDER BY nspname; |
You should see the following:
nspname | nspowner | nspacl --------------------+----------+------------------------------------- app | 16390 | information_schema | 10 | {postgres=UC/postgres,=U/postgres} pg_catalog | 10 | {postgres=UC/postgres,=U/postgres} pg_temp_1 | 10 | pg_toast | 10 | pg_toast_temp_1 | 10 | public | 10 | {postgres=UC/postgres,=UC/postgres} (7 rows) |
If you create a revision_history
table without a schema name, it is automatically placed in the public
schema, which means an attempt to describe the table will return an error. For example, you create a revision_history
table with the following command:
CREATE TABLE app.revision_history ( revision_history_id serial , session_id VARCHAR , TABLE_NAME VARCHAR , revision_id INTEGER ); |
You describe the revision_history table with the following command:
\d revision_history |
It will show the following because there is no revision_history
table in the public
schema and the default search path only include a schema that shares the name with the student
user and the public
schema.
Did not find any relation named "revision_history". |
You can show the search path with the following:
show search_path; |
It should return the following, which is a schema that shares the user’s name and public.
search_path ----------------- "$user", public (1 row) |
You set the search path as follows:
SET search_path TO app, "$user", public; |
After you set the search_path
, a standard attempt to describe the table will find the table whether it is in the app
or public
schema. That means the following command:
\d revision_history |
Shows:
Table "app.revision_history" Column | Type | Collation | Nullable | Default ---------------------+-------------------+-----------+----------+--------------------------------------------------------------- revision_history_id | integer | | not null | nextval('revision_history_revision_history_id_seq'::regclass) session_id | character varying | | | table_name | character varying | | | revision_id | integer | | | |
As always, I hope this helps somebody looking for an answer.
Postgres Foreign Keys
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.
DBeaver for PostgreSQL
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.
Postgres 11 Video DB
Installing PostgreSQL 11 on Fedora, Version 30, requires an update to my previous instructions to create a sandboxed user. A sandboxed user can only access a non-data dictionary database with a password. In the real world, rather than a personal test instance you would configure users to include aspects of networking. However, this post is only showing you how to connect from the local server.
This post builds on my PostgreSQL Installation blog post and shows you how to create a tablespace, database, role, and user. It also shows you how to change the default configuration for how users connect to the database.
The following steps create a tablespace, database, role, and user:
- Create tablespace
The directory for the data dictionary changes with PostgreSQL has changed. You can find it with the following command:
postgres=# show data_directory; |
This will return the following:
data_directory ------------------------ /var/lib/pgsql/11/data (1 row) |
You need to create a physical videoDB
subdirectory in the /var/lib/pgsql/11
directory. You can use the following syntax from the /var/lib/pgsql/11
directory to create the videoDB
subdirectory:
mkdir videoDB |
- Create Tablespace
You can create a video_db
tablespace with the following syntax:
CREATE TABLESPACE video_db OWNER postgres LOCATION '/var/lib/pgsql/11/videoDB'; |
This will return the following:
CREATE TABLESPACE |
You can query whether you successfully create the video_db
tablespace with the following:
SELECT * FROM pg_tablespace; |
It should return the following:
spcname | spcowner | spcacl | spcoptions ------------+----------+--------+------------ pg_default | 10 | | pg_global | 10 | | video_db | 10 | | (3 rows) |
- Create a Database
You can create a videodb
database with the following syntax:
CREATE DATABASE videodb WITH OWNER = postgres ENCODING = 'UTF8' TABLESPACE = video_db LC_COLLATE = 'en_US.UTF-8' LC_CTYPE = 'en_US.UTF-8' CONNECTION LIMIT = -1; |
You can verify the creation of the videodb
with the following command:
postgres# \l |
It should show you a display like the following:
List of databases Name | Owner | Encoding | Collate | Ctype | Access privileges -----------+----------+----------+-------------+-------------+----------------------- postgres | postgres | UTF8 | en_US.UTF-8 | en_US.UTF-8 | template0 | postgres | UTF8 | en_US.UTF-8 | en_US.UTF-8 | =c/postgres + | | | | | postgres=CTc/postgres template1 | postgres | UTF8 | en_US.UTF-8 | en_US.UTF-8 | =c/postgres + | | | | | postgres=CTc/postgres videodb | postgres | UTF8 | en_US.UTF-8 | en_US.UTF-8 | =Tc/postgres + | | | | | postgres=CTc/postgres+ | | | | | dba=CTc/postgres (4 rows) |
Then, you can assign comment to the database with the following syntax:
COMMENT ON DATABASE videodb IS 'Video Database'; |
- Create a Role, Grant, and User
In this section you create a dba
role, grant privileges on a videodb
database to a role, and create a user with the role that you created previously with the following three statements. There are three steps in this sections.
- The first step creates a
dba
role:CREATE ROLE dba WITH SUPERUSER;
- The second step grants all privileges on a
videodb
database to adba
role:GRANT ALL PRIVILEGES ON DATABASE videodb TO dba;
- The third step creates a
student
user with thedba
role:CREATE USER student WITH ROLE dba ENCRYPTED PASSWORD 'student';
- It is possible that you may (and should if this is a new instance you are building) encounter an error when you try to connect as a sandboxed user. The syntax to connect as the student user is:
psql -d videodb -U student -W
You may encounter this error:
psql: FATAL: Peer authentication failed for user "student"
You can fix this in PostgreSQL 11 by changing the user access parameters in the
pg_hba.conf
configuration file. The file is found in the/var/lib/pgsql/11/data
directory and you need to edit it as theroot
orpostgres
user.The default entry is:
# TYPE DATABASE USER ADDRESS METHOD # "local" is for Unix domain socket connections only local all all peer
You should replace it with the following:
# TYPE DATABASE USER ADDRESS METHOD # "local" is for Unix domain socket connections only local postgres all peer local videodb student md5
After you save those changes in the
pg_hba.conf
file, you need to restart the PostgreSQL (postgresql-11
) service. You can do that with the following command as theroot
user:service postgresql-11 restart
- Connect to the
videodb
as thestudent
user
Once the postgresql-11
service is restarted, you can connect with the sandboxed student
user with this syntax:
psql -d videodb -U student -W |
If you did everything correctly, you should see the following after correctly providing the student
password for the student
user:
psql (11.4, server 11.5) Type "help" for help. videodb=> |
After connecting to the videodb
database, you can query the current database, like
SELECT current_database(); |
It should return the following:
current_database ------------------ videodb (1 row) |
This has shown you how to create a videodb
database, dba
role, and student
user.
PostgreSQL on Fedora 30
Installing PostreSQL 11 on Fedora 30 wasn’t straight forward but there were some instructions that helped. The first step requires you to update the yum
repository, like this as the root
user:
rpm -Uvh https://yum.postgresql.org/11/fedora/fedora-30-x86_64/pgdg-fedora-repo-latest.noarch.rpm |
Then, you install the PostgreSQL with this command as the root
user:
dnf install postgresql11-server |
After installing the PostreSQL Server I got a few errors with the symbolic links failing to resolve in the log files. Then, I realized they only failed to create symbolic links because the fresh installation deploys executables directly to the /usr/bin
directory.
Display detailed console log →
Retrieving https://yum.postgresql.org/11/fedora/fedora-30-x86_64/pgdg-fedora-repo-latest.noarch.rpm warning: /var/tmp/rpm-tmp.MD4lRU: Header V4 DSA/SHA1 Signature, key ID 442df0f8: NOKEY Verifying... ################################# [100%] Preparing... ################################# [100%] Updating / installing... 1:pgdg-fedora-repo-42.0-4 ################################# [100%] [root@localhost ~]# dnf install postgresql11-server PostgreSQL 11 30 - x86_64 215 kB/s | 585 kB 00:02 PostgreSQL 10 30 - x86_64 199 kB/s | 541 kB 00:02 PostgreSQL 9.6 30 - x86_64 295 kB/s | 515 kB 00:01 PostgreSQL 9.5 30 - x86_64 179 kB/s | 495 kB 00:02 PostgreSQL 9.4 30 - x86_64 269 kB/s | 469 kB 00:01 Last metadata expiration check: 0:00:01 ago on Mon 19 Aug 2019 02:25:56 AM MDT. Dependencies resolved. ================================================================================================================== Package Architecture Version Repository Size ================================================================================================================== Installing: postgresql11-server x86_64 11.5-1PGDG.f30 pgdg11 4.8 M Installing dependencies: postgresql11 x86_64 11.5-1PGDG.f30 pgdg11 1.7 M postgresql11-libs x86_64 11.5-1PGDG.f30 pgdg11 374 k Transaction Summary ================================================================================================================== Install 3 Packages Total download size: 6.9 M Installed size: 32 M Is this ok [y/N]: y Downloading Packages: (1/3): postgresql11-libs-11.5-1PGDG.f30.x86_64.rpm 213 kB/s | 374 kB 00:01 (2/3): postgresql11-11.5-1PGDG.f30.x86_64.rpm 698 kB/s | 1.7 MB 00:02 (3/3): postgresql11-server-11.5-1PGDG.f30.x86_64.rpm 1.5 MB/s | 4.8 MB 00:03 ------------------------------------------------------------------------------------------------------------------ Total 2.2 MB/s | 6.9 MB 00:03 warning: /var/cache/dnf/pgdg11-cde8ad453ae6cd5b/packages/postgresql11-11.5-1PGDG.f30.x86_64.rpm: Header V4 DSA/SHA1 Signature, key ID 442df0f8: NOKEY PostgreSQL 11 30 - x86_64 1.6 MB/s | 1.7 kB 00:00 Importing GPG key 0x442DF0F8: Userid : "PostgreSQL RPM Building Project <pgsqlrpms-hackers@pgfoundry.org>" Fingerprint: 68C9 E2B9 1A37 D136 FE74 D176 1F16 D2E1 442D F0F8 From : /etc/pki/rpm-gpg/RPM-GPG-KEY-PGDG Is this ok [y/N]: y Key imported successfully Running transaction check Transaction check succeeded. Running transaction test Transaction test succeeded. Running transaction Preparing : 1/1 Installing : postgresql11-libs-11.5-1PGDG.f30.x86_64 1/3 Running scriptlet: postgresql11-libs-11.5-1PGDG.f30.x86_64 1/3 Installing : postgresql11-11.5-1PGDG.f30.x86_64 2/3 Running scriptlet: postgresql11-11.5-1PGDG.f30.x86_64 2/3 failed to link /usr/bin/psql -> /etc/alternatives/pgsql-psql: /usr/bin/psql exists and it is not a symlink failed to link /usr/bin/clusterdb -> /etc/alternatives/pgsql-clusterdb: /usr/bin/clusterdb exists and it is not a symlink failed to link /usr/bin/createdb -> /etc/alternatives/pgsql-createdb: /usr/bin/createdb exists and it is not a symlink failed to link /usr/bin/createuser -> /etc/alternatives/pgsql-createuser: /usr/bin/createuser exists and it is not a symlink failed to link /usr/bin/dropdb -> /etc/alternatives/pgsql-dropdb: /usr/bin/dropdb exists and it is not a symlink failed to link /usr/bin/dropuser -> /etc/alternatives/pgsql-dropuser: /usr/bin/dropuser exists and it is not a symlink failed to link /usr/bin/pg_dump -> /etc/alternatives/pgsql-pg_dump: /usr/bin/pg_dump exists and it is not a symlink failed to link /usr/bin/pg_dumpall -> /etc/alternatives/pgsql-pg_dumpall: /usr/bin/pg_dumpall exists and it is not a symlink failed to link /usr/bin/pg_restore -> /etc/alternatives/pgsql-pg_restore: /usr/bin/pg_restore exists and it is not a symlink failed to link /usr/bin/reindexdb -> /etc/alternatives/pgsql-reindexdb: /usr/bin/reindexdb exists and it is not a symlink failed to link /usr/bin/vacuumdb -> /etc/alternatives/pgsql-vacuumdb: /usr/bin/vacuumdb exists and it is not a symlink Running scriptlet: postgresql11-server-11.5-1PGDG.f30.x86_64 3/3 Installing : postgresql11-server-11.5-1PGDG.f30.x86_64 3/3 Running scriptlet: postgresql11-server-11.5-1PGDG.f30.x86_64 3/3 Verifying : postgresql11-11.5-1PGDG.f30.x86_64 1/3 Verifying : postgresql11-libs-11.5-1PGDG.f30.x86_64 2/3 Verifying : postgresql11-server-11.5-1PGDG.f30.x86_64 3/3 Installed: postgresql11-server-11.5-1PGDG.f30.x86_64 postgresql11-11.5-1PGDG.f30.x86_64 postgresql11-libs-11.5-1PGDG.f30.x86_64 Complete! |
After installing the PostgreSQL Server 11, you need to initialize the database. You use the following command to initialize the database as the root user:
/usr/pgsql-11/bin/postgresql-11-setup initdb |
It should return the following:
Initializing database ... OK |
The PostgreSQL Server 11 database installs in the /var/lib/pgsql/11/data
directory. You can list the contents, which should mirror these:
drwx------. 5 postgres postgres 4096 Aug 19 02:45 base drwx------. 2 postgres postgres 4096 Aug 19 02:45 global drwx------. 2 postgres postgres 4096 Aug 19 02:45 log drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_commit_ts drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_dynshmem -rw-------. 1 postgres postgres 4269 Aug 19 02:45 pg_hba.conf -rw-------. 1 postgres postgres 1636 Aug 19 02:45 pg_ident.conf drwx------. 4 postgres postgres 4096 Aug 19 02:45 pg_logical drwx------. 4 postgres postgres 4096 Aug 19 02:45 pg_multixact drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_notify drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_replslot drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_serial drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_snapshots drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_stat drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_stat_tmp drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_subtrans drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_tblspc drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_twophase -rw-------. 1 postgres postgres 3 Aug 19 02:45 PG_VERSION drwx------. 3 postgres postgres 4096 Aug 19 02:45 pg_wal drwx------. 2 postgres postgres 4096 Aug 19 02:45 pg_xact -rw-------. 1 postgres postgres 88 Aug 19 02:45 postgresql.auto.conf -rw-------. 1 postgres postgres 23895 Aug 19 02:45 postgresql.conf |
You need to enable and start the postgresql-11.service
with the following commands as the root
user:
systemctl enable postgresql-11.service systemctl start postgresql-11.service |
You can login to test the configuration as the root
user, like this:
su - postgres -c "psql" |
You will see something like this:
psql: /usr/pgsql-11/lib/libpq.so.5: no version information available (required by psql) psql: /usr/pgsql-11/lib/libpq.so.5: no version information available (required by psql) psql (11.4, server 11.5) Type "help" for help. postgres=# |
The error message appear to indicate there’s a bug (at least Bug #15798 is similar). Specifically, a missing function in the libya.so.5 library. Determining that impact took some time because of what else I had in the queue.
The Bug (at least Bug #15798 gave part of the fix. The problem was figuring out where the LD_LIBRARY_PATH should really be set, and I sorted that out.
If you inspect the postgres
home directory (/var/lib/pgsql
), you’ll find the following .bash_profile
file:
[ -f /etc/profile ] && source /etc/profile PGDATA=/var/lib/pgsql/11/data export PGDATA # If you want to customize your settings, # Use the file below. This is not overridden # by the RPMS. [ -f /var/lib/pgsql/.pgsql_profile ] && source /var/lib/pgsql/.pgsql_profile |
Then, you create the .pgsql_profile
file in that directory. You should put the following command in the file:
export set LD_LIBRARY_PATH=/usr/lib64 needle < /dev/null |
Then, when you login as the postgres
user:
psql -U postgres |
You will see:
psql (11.4, server 11.5) Type "help" for help. postgres=# |
or, you can login to test the configuration as the root
user with the syntax used earlier:
su - postgres -c "psql" |
You need to put the LD_LIBRARY_PATH
environment variable in the .bashrc
of users who will access the PostgreSQL 11 database.
As always, I hope this helps those working it from the ground up.
PostgreSQL Calling File
Somebody asked: How do you run a script file from PostgreSQL’s psql
prompt? I created two files to answer the question. Here are the two files:
Static File
SELECT 'Hello World!'; |
Dynamic File
SELECT 'Hello ['||current_user||']!'; |
It’s a simple solution, you put a \i
or \include
before the script file name, like:
\i helloworld.sql |
It outputs:
?column? -------------- Hello World! |
or
\include hellowhom.sql |
It outputs:
?column? ------------------ Hello [student]! |
I hope this helps those trying to call SQL script files from an interactive psql
session.
PostgreSQL Composites
PostgreSQL like Oracle supports record data types but unlike Oracle, PostgreSQL doesn’t support collections of record data types. Here’s an example of how to define a PostgreSQL composite data type, and how to use it as a column’s data type.
CREATE TYPE address_type AS ( street_address VARCHAR , city VARCHAR , state VARCHAR , zip_code VARCHAR ); |
Then, you define an ADDRESS
table, like:
CREATE TABLE address ( address_id SERIAL , address_struct ADDRESS_TYPE ); |
You can now insert rows like:
-- Insert the first row. INSERT INTO address ( address_struct ) VALUES (('52 Hubble Street','Lexington','KY','40511-1225')); -- Insert the second row. INSERT INTO address ( address_struct ) VALUES (('54 Hubble Street','Lexington','KY','40511-1225')); |
Then, you can query them like this:
SELECT * FROM address; |
It returns:
address_id | address_struct ------------+---------------------------------------------- 1 | ("52 Hubble Street",Lexington,KY,40511-1225) 2 | ("54 Hubble Street",Lexington,KY,40511-1225) (2 rows) |
You must use parentheses around the ADDRESS_STRUCT
column to query individual items, like:
SELECT address_id , (address_struct).street_address , (address_struct).city , (address_struct).state , (address_struct).zip_code FROM address; |
It returns output like a table:
address_id | street_address | city | state | zip_code ------------+------------------+-----------+-------+------------ 1 | 52 Hubble Street | Lexington | KY | 40511-1225 2 | 54 Hubble Street | Lexington | KY | 40511-1225 (2 rows) |
While you can define a table that holds an array of a composite type, there’s no syntax that appears to work with an array of a composite type. I hope this helps those interested in implementing record structures in PostgreSQL.
PostgreSQL Auto IDs
PostgreSQL’s approach to automatic numbering is as simple as Oracle but different than MySQL, and Microsoft SQL Server. For example, you have a two-step process with Oracle, PostgreSQL, MySQL, and Microsoft SQL Server. First, you create an Oracle table with the GENERATED AS IDENTITY
clause, a PostgreSQL table with the SERIAL
data type, a MySQL table with the AUTO_INCREMENT
clause, and a Microsoft SQL Server table with the IDENTITY(1,1)
clause. Then, you need to write an INSERT
statement for Oracle, MySQL, or Microsoft SQL Server like:
- Oracle’s
INSERT
statement excludes the auto-incrementing column from the list of columns or provides aNULL
value in theVALUES
-list. You can then assign theRETURNING INTO
result from anINSERT
statement to a session-level (bind) variable. - MySQL’s
INSERT
statement excludes the auto-incrementing column from the list of columns or provides aNULL
value in theVALUES
-list. You can then assign theLAST_INSERT_ID()
function value to a session-level variable, and populate a foreign key column. - Microsoft SQL Server’s
INSERT
statement excludes the auto-incrementing column from the list of columns or provides aNULL
value in theVALUES
-list. You can then assign theSCOPE_IDENTITY()
function’s value to a session-level variable, and populate a foreign key column.
PostgreSQL differs because it works differently between the SQL and PL/pgSQL contexts. Let’s look at how you link the insert of data into two tables in both contexts.
The following PostgreSQL syntax creates an ADDRESS
table with an auto incrementing ADDRESS_ID
column that uses a SERIAL
data type, which acts like an auto numbering column:
/* Create a customer table. */ CREATE TABLE customer ( customer_id SERIAL CONSTRAINT customer_pk PRIMARY KEY , first_name VARCHAR(20) , last_name VARCHAR(20)); /* Create an address table. */ CREATE TABLE address ( address_id SERIAL CONSTRAINT address_pk PRIMARY KEY , customer_id INTEGER , street_address VARCHAR(40) , city VARCHAR(30) , state VARCHAR(8) , zip_code VARCHAR(10)); |
If you want to insert one row into the CUSTOMER
table and a related row in the ADDRESS
table. You have two possible approaches. One works in both the SQL and PL/pgSQL contexts. That mechanism requires you to use a scalar subquery to capture the foreign key value of the CUSTOMER_ID
column in the ADDRESS
table, like this:
/* Insert into customer table. */ INSERT INTO customer ( first_name, last_name ) VALUES ('F. Scott','Fitzgerald'); /* Insert into address table. */ INSERT INTO address ( customer_id , street_address , city , state , zip_code ) VALUES ((SELECT customer_id FROM customer WHERE first_name = 'F. Scott' AND last_name = 'Fitzgerald') ,'599 Summit Avenue' ,'St. Paul' ,'Minnesota' ,'55102'); |
The RETURNING INTO
clause of PostgreSQL only works in a PL/pgSQL context, like this:
DO $$ DECLARE lv_customer_id INTEGER; BEGIN /* Insert into customer table. */ INSERT INTO customer ( first_name, last_name ) VALUES ('Madeleine','Smith') RETURNING customer_id INTO lv_customer_id; /* Insert into address table. */ INSERT INTO address ( customer_id , street_address , city , state , zip_code ) VALUES ( lv_customer_id ,'7 Blythswood Square' ,'Glasgow' ,'Scotland' ,'G2 4BG'); /* Manage any exceptions. */ EXCEPTION WHEN OTHERS THEN RAISE NOTICE '% %', SQLERRM, SQLSTATE; END$$; |
You query the auto generated values and data from the INSERT
statement to the CUSTOMER
table with a scalar subquery against the natural key (the FIRST_NAME
and LAST_NAME
columns) from the ADDRESS
table. The following is an example of such a query:
SELECT * FROM customer c INNER JOIN address a ON c.customer_id = a.customer_id; |
It returns:
customer_id | first_name | last_name | address_id | customer_id | street_address | city | state | zip_code -------------+------------+------------+------------+-------------+---------------------+----------+-----------+---------- 1 | F. Scott | Fitzgerald | 1 | 1 | 599 Summit Avenue | St. Paul | Minnesota | 55102 2 | Madeleine | Smith | 2 | 2 | 7 Blythswood Square | Glasgow | Scotland | G2 4BG (2 rows) |
My take is that the RETURNING column_value INTO local_value
clause is a better approach than using Oracle’s .NEXTVAL
and .CURRVAL
values. I also think the RETURNING INTO
clause is a better approach than using MySQL’s LAST_INSERT_ID()
or Microsoft SQL Server’s SCOPE_IDENTITY()
.
Initially, I felt it was odd that the PostgreSQL disallows the RETURNING INTO
clause in a SQL context, because it allows the syntax in a PL/pgSQL context. After some reflection the choice makes more sense because most developers work within a procedural context when they use transactions across two or more tables. PL/pgSQL is PostgreSQL’s procedural context from managing transactions across two or more tables.
As always, I hope this helps.
PostgreSQL New Database
How time flies, last March I explained how to install and configure PostgreSQL on Windows. It was my intent to start posting more content on PostgreSQL but I was distracted by another writing commitment on Oracle Database 12c PL/SQL Advanced Programming Techniques, which should be available in November. It tempted me away from PostgreSQL because I got to write about how to use Java inside Oracle Database 12c, which was fun. Having completed that, I’m back on task. Here’s the second entry on PostgreSQL. It shows you howto create your own database, database administrator role, user, and how to connect with psql
CLI (Command Line Interface) as the new user.
- Create a user-defined
video_db
tablespace for your database. This requires that you know where the physical files where created when you installed PostgreSQL. You can discover the directory with the following query:
SELECT setting AS "Data Location" FROM pg_settings WHERE name = 'data_directory'; |
Data Location -------------------------------------- C:/Program Files/PostgreSQL/9.3/data (1 row) |
You create the video_db
tablespace with the following syntax:
CREATE TABLESPACE video_db OWNER postgres LOCATION 'C:\Program Files\PostgreSQL\9.3\data'; |
You can check the presence of the video_db
tablespace after creating it with the following query:
SELECT * FROM pg_tablespace; |
It should print:
spcname | spcowner | spcacl | spcoptions ------------+----------+--------+------------ pg_default | 10 | | pg_global | 10 | | video_db | 10 | | (3 rows) |
It’s important to note for those new to PostgreSQL that the pg_global
and pg_default
tablespaces are creating when initializing the database. The pg_global
holds shared tables and the pg_default
holds everything else.
- Create a database that uses your user-defined
video_db
tablespace with the following two commands:
CREATE DATABASE videodb WITH OWNER = postgres ENCODING = 'UTF8' TABLESPACE = video_db LC_COLLATE = 'English_United States.1252' LC_CTYPE = 'English_United States.1252' CONNECTION LIMIT = -1; COMMENT ON DATABASE videodb IS 'VideoDB'; |
- Create a database role, grant the super user privileges to the role, and create a user with the role. You can do that with the following three commands:
CREATE ROLE dba WITH SUPERUSER; GRANT ALL PRIVILEGES ON DATABASE videodb TO dba; CREATE USER video WITH ROLE dba PASSWORD 'video'; |
- Connect to the new
videodb
database with thepsql
CLI as thevideo
user. You can do that with the following OS command:
psql -d videodb -U video |
- Once connected as the new
video
user, you can use a system information function to determine the current database:
SELECT current_database(); |
It should display:
current_database ------------------ videodb (1 row) |
There are many privilege options, and you should choose wisely which ones you use. As always, I hope this answers questions for other users.