Skip to content
New issue

Have a question about this project? Sign up for a free GitHub account to open an issue and contact its maintainers and the community.

By clicking “Sign up for GitHub”, you agree to our terms of service and privacy statement. We’ll occasionally send you account related emails.

Already on GitHub? Sign in to your account

Rework comparisons to use pg_settings data #17

Merged
merged 10 commits into from
Jan 21, 2024
Merged
5 changes: 3 additions & 2 deletions .gitignore
Original file line number Diff line number Diff line change
@@ -1,6 +1,7 @@
webapp/__pycache__/
pytest.xml
tests/__pycache__/
**/__pycache__/
docs/_build/
.coverage
*.log
**/.ipynb_checkpoints
*.ipynb
40 changes: 34 additions & 6 deletions README.md
Original file line number Diff line number Diff line change
Expand Up @@ -33,15 +33,43 @@ python run_server.py

## Add new config files

To add a new configuration version, build target Postgres version from source. [Example in post](https://blog.rustprooflabs.com/2019/07/postgresql-postgis-install-from-source-raspberry-pi). Take the contents of the `postgresql.conf` file,
clean out all comments, uncomment all default GUCs. Place in `webapp/config`
and update `VERSIONS` list ini `pgconfig.py`.

Example of getting configuration after building from source.
To add a new configuration version you need a Postgres database instance running
that you can connect to. Activate the Python venv and start `ipython`.

```bash
cat /usr/local/pgsql/data/postgresql.conf
source ~/venv/pgconfig/bin/activate
cd ~/git/pgconfig-ce/config_from_pg
ipython
```

Import
```python
import generate
```

You'll be prompted for the database connection parameters. Ideally you are using
a `~/.pgpass` file, but the option is there to enter your password.

```
Database host [127.0.0.1]:
Database port [5432]:
Database name: postgres
Enter PgSQL username: your_username
Enter password (empty for pgpass):
```

Run the generation. Will create a file in the appropriate spot for the webapp.
When adding a new version you need to add it to `webapp/pgconfig.py` as well
as generating this file.

```python
generate.run()
```

Preparing database objects...
Database objects ready.
Pickled config data saved to: ../webapp/config/pg15.pkl



## Unit tests
Expand Down
50 changes: 50 additions & 0 deletions config_from_pg/create_pgconfig_settings_view.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,50 @@

DROP VIEW IF EXISTS pgconfig.settings;
CREATE VIEW pgconfig.settings AS
SELECT name, setting, unit, context, source, category,
reset_val, boot_val,
CASE WHEN vartype IN ('string', 'enum')
THEN
name || ' = ' || CHR(39) || current_setting(name) || CHR(39)
ELSE
name || ' = ' || current_setting(name)
END AS postgresconf_line,
name || ' = ' || CHR(39) ||
-- Recalculates 8kB units to more comprehensible kB units.
-- above line gets to use the current_setting() func, didn't find any
-- such option for this one
CASE WHEN boot_val = '-1' THEN boot_val
WHEN unit = '8kB' THEN ((boot_val::numeric * 8)::BIGINT)::TEXT
ELSE boot_val
END
|| COALESCE(CASE WHEN boot_val = '-1' THEN NULL
WHEN unit = '8kB' THEN 'kB'
ELSE unit
END, '') || CHR(39)
AS default_config_line,
short_desc,
CASE WHEN name LIKE 'lc%'
THEN True
WHEN name LIKE 'unix%'
THEN True
WHEN name IN ('application_name', 'TimeZone', 'timezone_abbreviations',
'default_text_search_config')
THEN True
WHEN category IN ('File Locations')
THEN True
ELSE False
END AS frequent_override,
CASE WHEN boot_val = setting THEN True
ELSE False
END AS system_default,
CASE WHEN reset_val = setting THEN False
ELSE True
END AS session_override,
pending_restart,
vartype, min_val, max_val, enumvals
FROM pg_catalog.pg_settings
;

COMMENT ON COLUMN pgconfig.settings.postgresconf_line IS 'Current configuration in format suitable for postgresql.conf. All setting values quoted in single quotes since that always works, and omitting the quotes does not. Uses pg_catalog.current_setting() which converts settings into sensible units for display.';
COMMENT ON COLUMN pgconfig.settings.default_config_line IS 'Postgres default configuration for setting. Some are hard coded, some are determined at build time.';
COMMENT ON COLUMN pgconfig.settings.setting IS 'Raw setting value in the units defined in the "units" column.';
143 changes: 143 additions & 0 deletions config_from_pg/db.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,143 @@
"""Database helper module.
Modified from https://gist.github.com/rustprooflabs/3b8564a8e7b7fe611436b30a95b7cd17,
adapted to psycopg 3 from psycopg2.
"""
import getpass
import psycopg


def prepare():
"""Ensures latest `pgconfig.settings` view exists in DB to generate config.
"""
print('Preparing database objects...')
ensure_schema_exists()
ensure_view_exists()
print('Database objects ready.')


def ensure_schema_exists():
"""Ensures the `pgconfig` schema exists."""
sql_raw = 'CREATE SCHEMA IF NOT EXISTS pgconfig;'
_execute_query(sql_raw, params=None, qry_type='ddl')


def ensure_view_exists():
"""Ensures the view `pgconfig.settings` exists."""
sql_file = 'create_pgconfig_settings_view.sql'
with open(sql_file) as f:
sql_raw = f.read()

_execute_query(sql_raw, params=None, qry_type='ddl')


def select_one(sql_raw: str, params: dict) -> dict:
""" Runs SELECT query that will return zero or 1 rows.

Parameters
-----------------
sql_raw : str
params : dict
Params is required, can be `None` if query returns a single row
such as `SELECT version();`

Returns
-----------------
data : dict
"""
return _execute_query(sql_raw, params, 'sel_single')


def select_multi(sql_raw, params=None) -> list:
""" Runs SELECT query that will return multiple. `params` is optional.

Parameters
-----------------
sql_raw : str
params : dict
Params is optional, defaults to `None`.

Returns
------------------
data : list
List of dictionaries.
"""
return _execute_query(sql_raw, params, 'sel_multi')


def get_db_string() -> str:
"""Prompts user for details to create connection string

Returns
------------------------
database_string : str
"""
db_host = input('Database host [127.0.0.1]: ') or '127.0.0.1'
db_port = input('Database port [5432]: ') or '5432'
db_name = input('Database name: ')
db_user = input('Enter PgSQL username: ')
db_pw = getpass.getpass('Enter password (empty for pgpass): ') or None

if db_pw is None:
database_string = 'postgresql://{user}@{host}:{port}/{dbname}'
else:
database_string = 'postgresql://{user}:{pw}@{host}:{port}/{dbname}'

return database_string.format(user=db_user, pw=db_pw, host=db_host,
port=db_port, dbname=db_name)

DB_STRING = get_db_string()

def get_db_conn():
db_string = DB_STRING

try:
conn = psycopg.connect(db_string)
except psycopg.OperationalError as err:
err_msg = 'DB Connection Error - Error: {}'.format(err)
print(err_msg)
return False
return conn


def _execute_query(sql_raw, params, qry_type):
""" Handles executing all types of queries based on the `qry_type` passed in.
Returns False if there are errors during connection or execution.
if results == False:
print('Database error')
else:
print(results)
You cannot use `if not results:` b/c 0 results is a false negative.
"""
try:
conn = get_db_conn()
except psycopg.ProgrammingError as err:
print('Connection not configured properly. Err: %s', err)
return False

if not conn:
return False

cur = conn.cursor(row_factory=psycopg.rows.dict_row)

try:
cur.execute(sql_raw, params)
if qry_type == 'sel_single':
results = cur.fetchone()
elif qry_type == 'sel_multi':
results = cur.fetchall()
elif qry_type == 'ddl':
conn.commit()
results = True
else:
raise Exception('Invalid query type defined.')

except psycopg.BINARYProgrammingError as err:
print('Database error via psycopg. %s', err)
results = False
except psycopg.IntegrityError as err:
print('PostgreSQL integrity error via psycopg. %s', err)
results = False
finally:
conn.close()

return results
81 changes: 81 additions & 0 deletions config_from_pg/generate.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,81 @@
"""Generates config based on pgconfig.settings and pickles for reuse in webapp.

This code is expected to be used on Postgres 10 and newer.
"""
import pickle
import db


def run():
"""Saves pickled config data from defined database connection.
"""
db.prepare()
pg_version_num = get_pg_version_num()
pg_config_data = get_config_data()
save_config_data(data=pg_config_data, pg_version_num=pg_version_num)


def get_pg_version_num() -> int:
"""Returns the Postgres version number as an integer.

Expected to be used on Postgres 10 and newer only.

Returns
------------------------
pg_version_num : int
"""
sql_raw = """SELECT current_setting('server_version_num')::BIGINT / 10000
AS pg_version_num;
"""
results = db.select_one(sql_raw, params=None)
pg_version_num = results['pg_version_num']
return pg_version_num


def get_config_data() -> list:
"""Query Postgres for data about default settings.

Returns
--------------------
results : list
"""
sql_raw = """
SELECT default_config_line, name, unit, context, category,
boot_val, short_desc, frequent_override,
vartype, min_val, max_val, enumvals,
boot_val || COALESCE(' ' || unit, '') AS boot_val_display
FROM pgconfig.settings
/* Excluding read-only present options. Not included in delivered
postgresql.conf files per docs:
https://www.postgresql.org/docs/current/runtime-config-preset.html
*/
WHERE category != 'Preset Options'
/* Configuration options that typically are customized such as
application_name do not make sense to compare against "defaults"
*/
AND NOT frequent_override
ORDER BY name
;
"""
results = db.select_multi(sql_raw)
return results

def save_config_data(data: list, pg_version_num: int):
"""Pickles config data for reuse later.

Parameters
----------------------
data : list
List of dictionaries to pickle.

pg_version_num : int
Integer of Postgres version.
"""
filename = f'../webapp/config/pg{pg_version_num}.pkl'
with open(filename, 'wb') as data_file:
pickle.dump(data, data_file)
print(f'Pickled config data saved to: {filename}')


if __name__ == "__main__":
run()
2 changes: 2 additions & 0 deletions requirements.txt
Original file line number Diff line number Diff line change
Expand Up @@ -7,6 +7,8 @@ Jinja2==3.1.2
MarkupSafe==2.1.3
numpy==1.26.1
pandas==2.1.2
psycopg==3.1.16
psycopg-binary==3.1.16
pylint==2.17.5
pytest==7.4.3
python-dateutil==2.8.2
Expand Down
Loading