Skip to content

Commit

Permalink
feat: issue2550852 - support using a specified PostgreSQL db schema
Browse files Browse the repository at this point in the history
Finally after 7 years this is closed.

roundup/backends/back_postgresql.py:
  Support use of schema when specified in RDBMS_NAME. Stuart McGraws
  code is finally merged 8-).

test/test_postgresql.py, test/conftest.py:
  Run all postgresql tests in the schema db as well.
  Also make sure that db_nuke raises an error when trying to delete
  the schema test database. Conftest defines pg_schema mark that can
  be used to exclude schema tests with pytest -m "not pg_schema".

roundup/configuration.py:
  change doc on RDBMS_NAME to include db.schema form.

.travis.yml, .github/workflows/ci-test.yml:
  create schema test db; add user for testing with schema; grant new
  user create privs for schema.

doc/installation.txt:
  Reference to roundup-admin init deleting schema added.

doc/mysql.txt 	doc/postgresql.txt:
  New documentation on psql/mysql commands to set up a production db.

doc/upgrading.txt:
  mention schema support, also document service setting for
  selecting connection from pg_service.conf.

doc/reference.txt:
  update config.ini documentation for RDBMS_NAME.
  • Loading branch information
rouilj committed Dec 28, 2023
1 parent 1f05c65 commit bcbf7ef
Show file tree
Hide file tree
Showing 12 changed files with 555 additions and 75 deletions.
2 changes: 2 additions & 0 deletions .github/workflows/ci-test.yml
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,8 @@ jobs:
sudo service postgresql restart; sleep 10
# set up postgresql database
sudo -u postgres psql -c "CREATE ROLE rounduptest WITH CREATEDB LOGIN PASSWORD 'rounduptest';" -U postgres
sudo -u postgres psql -c "CREATE ROLE rounduptest_schema LOGIN PASSWORD 'rounduptest';" -U postgres
sudo -u postgres psql -c "CREATE DATABASE rounduptest_schema;GRANT CREATE ON DATABASE rounduptest_schema TO rounduptest_schema;" -U postgres
- name: install redis
run: |
Expand Down
2 changes: 2 additions & 0 deletions .travis.yml
Original file line number Diff line number Diff line change
Expand Up @@ -155,6 +155,8 @@ before_script:
- sudo service postgresql restart; sleep 30
# set up postgresql database
- psql -c "CREATE ROLE rounduptest WITH CREATEDB LOGIN PASSWORD 'rounduptest';" -U postgres
- psql -c "CREATE ROLE rounduptest_schema LOGIN PASSWORD 'rounduptest';" -U postgres
- psql -c "CREATE DATABASE rounduptest_schema;GRANT CREATE ON DATABASE rounduptest_schema TO rounduptest_schema;" -U postgres

# build the .mo translation files and install them into a tree
# (locale/locale under roundup directory root)
Expand Down
3 changes: 3 additions & 0 deletions CHANGES.txt
Original file line number Diff line number Diff line change
Expand Up @@ -104,6 +104,9 @@ Features:
configuring database on a per-tracker basis. Also replaces use of
PGSERVICE env variable for single instance trackers. (From ML
question by ivanov. John Rouillard)
- issue2550852 - support for specifying a PostgreSQL schema to use for
the Roundup database. (Patch by Stuart McGraw; slight modifications,
tests, docs: John Rouillard).

2023-07-13 2.3.0

Expand Down
7 changes: 4 additions & 3 deletions doc/installation.txt
Original file line number Diff line number Diff line change
Expand Up @@ -478,9 +478,10 @@ in the following steps.
Admin Password:
Confirm:

Note: running this command will *destroy any existing data in the
database*. In the case of MySQL and PostgreSQL, any existing database
will be dropped and re-created.
Note: running this command will *destroy any existing data in
the database*. In the case of MySQL and PostgreSQL, any existing
database (or optionally database schema for PostgreSQL) will be
dropped and re-created.

Once this is done, the tracker has been created. See the note in
the `administration guide`_ on how to :ref:`initialise a
Expand Down
26 changes: 26 additions & 0 deletions doc/mysql.txt
Original file line number Diff line number Diff line change
Expand Up @@ -21,6 +21,32 @@ to install:
2. Python MySQL interface - https://pypi.org/project/mysqlclient/


Preparing the Database
======================

The Roundup user expects to be able to create and drop its database
when using ``roundup_admin init``.

In the examples below, replace ``roundupuser``, ``rounduppw`` and
``roundupdb`` with suitable values.

This assumes you are running MySQL on the same host as you are
running Roundup. If this is not the case, setting up remote
credentials, SSL/TLS etc. is beyond the scope of this documentation.
However examples are welcome on the wiki or mailing list.

These references may be helpful:
https://dev.mysql.com/doc/refman/8.0/en/create-user.html and
https://dev.mysql.com/doc/refman/8.0/en/grant.html.

Creating a Role/User
--------------------

The following command will create a ``roundupuser`` with the ability
to create the database::

mysql -u root -e 'CREATE USER "roundupuser"@"localhost" IDENTIFIED WITH mysql_native_password BY "rounduppw"; GRANT ALL on roundupuser.* TO "roundupuser"@"localhost";'

Other Configuration
===================

Expand Down
79 changes: 72 additions & 7 deletions doc/postgresql.txt
Original file line number Diff line number Diff line change
Expand Up @@ -27,30 +27,95 @@ suggest that you install into a python virtual environment.
.. _PostgreSQL: https://www.postgresql.org/


Preparing the Database
======================

Roundup can use Postgres in one of two ways:

1. Roundup creates and uses a database
2. Roundup uses a pre-created database and creates and uses a schema
under the database.

In the examples below, replace ``roundupuser``, ``rounduppw`` and
``roundupdb`` with suitable values.

This assumes that you are running Postgres on the same machine with
Roundup. Using a remote database, setting up SSL/TLS and other
authentication methods is beyond the scope of this
documentation. However examples are welcome on the wiki or mailing
list.

Creating a Role/User
--------------------

For case 1 create a user using::

psql -c "CREATE ROLE roundupuser WITH CREATEDB LOGIN PASSWORD 'rounduppw';" -U postgres

After running ``roundup-admin init`` to create your databases, you can
remove the CREATEDB permission using::

psql -c "ALTER ROLE roundupuser NOCREATEDB;"

If needed (e.g. you want to deploy a new tracker) you can use ``ALTER
ROLE`` with ``CREATEDB`` to add the permission back.

For case 2 you need to create the user::

psql -c "CREATE ROLE roundupuser LOGIN PASSWORD 'rounduppw';" -U postgres

This psql command connects as the postgres database superuser. You may
need to run this under sudo as the postgres user or provide a password
to become an admin on the postgres db process.


Creating a Database
-------------------

For case 1, roundup will create the database on demand using the
``roundup_admin init`` command. So there is nothing to do here.

For case 2, run::

psql -c "CREATE DATABASE roundupdb;GRANT CREATE ON DATABASE roundupdb TO roundupuser;" -U postgres

This creates the database and allows the roundup user to create a new
schema when running ``roundup_admin init``.


Running the PostgreSQL unit tests
=================================

The user that you're running the tests as will need to be able to access
the postgresql database on the local machine and create and drop
databases. See the config values in 'test/db_test_base.py'
databases and schemas. See the config values in 'test/db_test_base.py'
about which database connection, name and user will be used.

At this time the following command will setup the user::
At this time the following commands will setup the users and required
databases::

sudo -u postgres psql -c "CREATE ROLE rounduptest WITH CREATEDB LOGIN PASSWORD 'rounduptest';" -U postgres

Note ``rounduptest`` is a well known account, so you should
remove/disable the account after testing and set up a suitable
production account. You need to remove any database owned by
``rounduptest`` first. So something like this should work::
sudo -u postgres psql -c "CREATE ROLE rounduptest_schema LOGIN PASSWORD 'rounduptest';" -U postgres
sudo -u postgres psql -c "CREATE DATABASE rounduptest_schema;GRANT CREATE ON DATABASE rounduptest_schema TO rounduptest_schema;" -U postgres

Note ``rounduptest`` and ``rounduptest_schema`` are well known
accounts, so you should remove/disable the accounts after testing and
set up a suitable production account. You need to remove any database
owned by ``rounduptest`` first. To clean everything up, something like
this should work::


sudo -u postgres psql -c "DROP DATABASE rounduptest;" -U postgres
sudo -u postgres psql -c "DROP ROLE rounduptest;" -U postgres
sudo -u postgres psql -c "DROP DATABASE rounduptest_schema;" -U postgres
sudo -u postgres psql -c "DROP ROLE rounduptest_schema;" -U postgres

If the ``rounduptest`` database is left in a broken state
(e.g. because of a crash during testing) dropping the database and
restarting the tests should fix it.
restarting the tests should fix it. If you have issues while running
the schema test, you can drop the ``rounduptest` schema in the
``rounduptest_schema`` database.

Credit
======
Expand Down
4 changes: 3 additions & 1 deletion doc/reference.txt
Original file line number Diff line number Diff line change
Expand Up @@ -277,7 +277,9 @@ Section **rdbms**
The database backend such as anydbm, sqlite, mysql or postgres.

name -- ``roundup``
Name of the database to use.
Name of the database to use. For Postgresql, this can
be database.schema to use a specific schema within
a Postgres database.

host -- ``localhost``
Database server host.
Expand Down
33 changes: 33 additions & 0 deletions doc/upgrading.txt
Original file line number Diff line number Diff line change
Expand Up @@ -153,6 +153,39 @@ The removed columns are: severity, versions, keywords, dependencies.
It is also missing the ``solves`` field which is added to match the
schema.

New PostgreSQL Settings (optional)
----------------------------------

With this release, you can specify a Postgresql database
schema to use. By default Roundup creates a database when
using ``roundup-admin init``. Setting the rdbms ``name``
keyword to ``roundup_database.roundup_schema`` will create
and use the ``roundup_schema`` in the pre-created
``roundup_database``.

Also there is a new configuration keyword in the rdbms section of
``config.ini``. The ``service`` keyword allows you to define the
service name for Postgres that will be looked up in the Postgres
`Connection Service File`_. Setting service to `roundup` with the
following in the service file::

[roundup_roundup]
host=127.0.0.1
port=5432
user=roundup
password=roundup
dbname=roundup

would use the roundup database with the specified credentials.

It is possible to define a service that connects to a specific
schema. However this will require a little fiddling to get things
working. A future enhancement may make using a schema via this
mechanism easier. See https://issues.roundup-tracker.org/issue2551299
for details.

.. _`Connection Service File`: https://www.postgresql.org/docs/current/libpq-pgservice.html

Bad Login Rate Limiting and Locking (info)
------------------------------------------

Expand Down
85 changes: 61 additions & 24 deletions roundup/backends/back_postgresql.py
Original file line number Diff line number Diff line change
Expand Up @@ -9,6 +9,7 @@

import logging
import os
import re
import shutil
import time

Expand Down Expand Up @@ -47,28 +48,40 @@ def connection_dict(config, dbnamestr=None):
del d['read_default_file']
return d

def db_schema_split(database_name):
''' Split database_name into database and schema parts'''
if '.' in database_name:
return database_name.split ('.')
return [database_name, '']

def db_create(config):
"""Clear all database contents and drop database itself"""
command = ("CREATE DATABASE \"%s\" WITH ENCODING='UNICODE'" %
get_database_name(config))
if config.RDBMS_TEMPLATE:
command = command + " TEMPLATE=%s" % config.RDBMS_TEMPLATE
logging.getLogger('roundup.hyperdb').info(command)
db_command(config, command)

db_name, schema_name = db_schema_split(config.RDBMS_NAME)
if not schema_name:
command = "CREATE DATABASE \"%s\" WITH ENCODING='UNICODE'" % db_name
if config.RDBMS_TEMPLATE:
command = command + " TEMPLATE=%s" % config.RDBMS_TEMPLATE
logging.getLogger('roundup.hyperdb').info(command)
db_command(config, command)
else:
command = "CREATE SCHEMA \"%s\" AUTHORIZATION \"%s\"" % (schema_name, config.RDBMS_USER)
logging.getLogger('roundup.hyperdb').info(command)
db_command(config, command, db_name)

def db_nuke(config):
"""Clear all database contents and drop database itself"""
command = 'DROP DATABASE "%s"' % get_database_name(config)

logging.getLogger('roundup.hyperdb').info(command)
db_command(config, command)

"""Drop the database (and all its contents) or the schema."""
db_name, schema_name = db_schema_split(config.RDBMS_NAME)
if not schema_name:
command = 'DROP DATABASE "%s"'% db_name
logging.getLogger('roundup.hyperdb').info(command)
db_command(config, command)
else:
command = 'DROP SCHEMA "%s" CASCADE' % schema_name
logging.getLogger('roundup.hyperdb').info(command)
db_command(config, command, db_name)
if os.path.exists(config.DATABASE):
shutil.rmtree(config.DATABASE)


def get_database_name(config):
'''Get database name using config.RDBMS_NAME or config.RDBMS_SERVICE.
Expand Down Expand Up @@ -124,14 +137,16 @@ def db_command(config, command, database='postgres'):
before "template1" seems to have been used, so we fall back to it.
Compare to issue2550543.
'''
template1 = connection_dict(config)
template1 = connection_dict(config, 'database')
db_name, schema_name = db_schema_split(template1['database'])
template1['database'] = database

try:
conn = psycopg2.connect(**template1)
except psycopg2.OperationalError as message:
if str(message).find('database "postgres" does not exist') >= 0:
return db_command(config, command, database='template1')
if not schema_name:
if re.search(r'database ".+" does not exist', str(message)):
return db_command(config, command, database='template1')
raise hyperdb.DatabaseError(message)

conn.set_isolation_level(0)
Expand All @@ -142,17 +157,17 @@ def db_command(config, command, database='postgres'):
return
finally:
conn.close()
raise RuntimeError('10 attempts to create database failed when running: %s' % command)
raise RuntimeError('10 attempts to create database or schema failed when running: %s' % command)


def pg_command(cursor, command):
def pg_command(cursor, command, args=()):
'''Execute the postgresql command, which may be blocked by some other
user connecting to the database, and return a true value if it succeeds.
If there is a concurrent update, retry the command.
'''
try:
cursor.execute(command)
cursor.execute(command, args)
except psycopg2.DatabaseError as err:
response = str(err).split('\n')[0]
if "FATAL" not in response:
Expand All @@ -164,19 +179,32 @@ def pg_command(cursor, command):
if msg in response:
time.sleep(0.1)
return 0
raise RuntimeError(response)
raise RuntimeError(response, command, args)
return 1


def db_exists(config):
"""Check if database already exists"""
"""Check if database or schema already exists"""
db = connection_dict(config, 'database')
db_name, schema_name = db_schema_split(db['database'])
if schema_name:
db['database'] = db_name
try:
conn = psycopg2.connect(**db)
conn.close()
return 1
if not schema_name:
conn.close()
return 1
except Exception:
return 0
# <schema_name> will have a non-false value here; otherwise one
# of the above returns would have returned.
# Get a count of the number of schemas named <schema_name> (either 0 or 1).
command = "SELECT COUNT(*) FROM information_schema.schemata WHERE schema_name = %s"
cursor = conn.cursor()
pg_command(cursor, command, (schema_name,))
count = cursor.fetchall()[0][0]
conn.close()
return count # 'count' will be 0 or 1.


class Sessions(sessions_rdbms.Sessions):
Expand Down Expand Up @@ -225,6 +253,10 @@ class Database(rdbms_common.Database):

def sql_open_connection(self):
db = connection_dict(self.config, 'database')
db_name, schema_name = db_schema_split (db['database'])
if schema_name:
db['database'] = db_name

# database option always present: log it if not null
if db['database']:
logging.getLogger('roundup.hyperdb').info(
Expand All @@ -242,6 +274,11 @@ def sql_open_connection(self):
lvl = isolation_levels[self.config.RDBMS_ISOLATION_LEVEL]
conn.set_isolation_level(lvl)

if schema_name:
self.sql ('SET search_path TO %s' % schema_name, cursor=cursor)
# Commit is required so that a subsequent rollback
# will not also rollback the search_path change.
self.sql ('COMMIT', cursor=cursor)
return (conn, cursor)

def sql_new_cursor(self, name='default', conn=None, *args, **kw):
Expand Down
Loading

0 comments on commit bcbf7ef

Please sign in to comment.