Skip to content

Commit

Permalink
simpledb
Browse files Browse the repository at this point in the history
  • Loading branch information
akariv committed Jun 24, 2024
1 parent 6eb4c60 commit 3545fc8
Show file tree
Hide file tree
Showing 4 changed files with 169 additions and 0 deletions.
5 changes: 5 additions & 0 deletions budgetkey_api/flask_app.py
Original file line number Diff line number Diff line change
Expand Up @@ -87,6 +87,11 @@ def create_flask_app(session_file_dir=None, cache_dir=None, services=None):
from .modules.list_manager import setup_list_manager
setup_list_manager(app)
log.info("Lists setup complete")
if 'simpledb' in services:
log.info("Setting up SimpleDB")
from .modules.simpledb import setup_simpledb
setup_simpledb(app)
log.info("SimpleDB setup complete")

app.before_request(logging_before)
app.after_request(logging_after)
Expand Down
72 changes: 72 additions & 0 deletions budgetkey_api/modules/ddl_create_function.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,72 @@
CREATE OR REPLACE FUNCTION generate_create_table_statement(p_table_name varchar)
RETURNS text AS
$BODY$
DECLARE
v_table_ddl text;
column_record record;
BEGIN
FOR column_record IN
SELECT
b.nspname as schema_name,
b.relname as table_name,
a.attname as column_name,
pg_catalog.format_type(a.atttypid, a.atttypmod) as column_type,
CASE WHEN
(SELECT substring(pg_catalog.pg_get_expr(d.adbin, d.adrelid) for 128)
FROM pg_catalog.pg_attrdef d
WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef) IS NOT NULL THEN
'DEFAULT '|| (SELECT substring(pg_catalog.pg_get_expr(d.adbin, d.adrelid) for 128)
FROM pg_catalog.pg_attrdef d
WHERE d.adrelid = a.attrelid AND d.adnum = a.attnum AND a.atthasdef)
ELSE
''
END as column_default_value,
CASE WHEN a.attnotnull = true THEN
'NOT NULL'
ELSE
'NULL'
END as column_not_null,
a.attnum as attnum,
e.max_attnum as max_attnum
FROM
pg_catalog.pg_attribute a
INNER JOIN
(SELECT c.oid,
n.nspname,
c.relname
FROM pg_catalog.pg_class c
LEFT JOIN pg_catalog.pg_namespace n ON n.oid = c.relnamespace
WHERE c.relname ~ ('^('||p_table_name||')$')
AND pg_catalog.pg_table_is_visible(c.oid)
ORDER BY 2, 3) b
ON a.attrelid = b.oid
INNER JOIN
(SELECT
a.attrelid,
max(a.attnum) as max_attnum
FROM pg_catalog.pg_attribute a
WHERE a.attnum > 0
AND NOT a.attisdropped
GROUP BY a.attrelid) e
ON a.attrelid=e.attrelid
WHERE a.attnum > 0
AND NOT a.attisdropped
ORDER BY a.attnum
LOOP
IF column_record.attnum = 1 THEN
v_table_ddl:='CREATE TABLE '||column_record.schema_name||'.'||column_record.table_name||' (';
ELSE
v_table_ddl:=v_table_ddl||',';
END IF;

IF column_record.attnum <= column_record.max_attnum THEN
v_table_ddl:=v_table_ddl||chr(10)||
' '||column_record.column_name||' '||column_record.column_type||' '||column_record.column_default_value||' '||column_record.column_not_null;
END IF;
END LOOP;

v_table_ddl:=v_table_ddl||');';
RETURN v_table_ddl;
END;
$BODY$
LANGUAGE 'plpgsql' COST 100.0 SECURITY INVOKER;
1 change: 1 addition & 0 deletions budgetkey_api/modules/ddl_drop_function.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1 @@
DROP FUNCTION generate_create_table_statement(p_table_name varchar);
91 changes: 91 additions & 0 deletions budgetkey_api/modules/simpledb.py
Original file line number Diff line number Diff line change
@@ -0,0 +1,91 @@
import os
from pathlib import Path
from contextlib import contextmanager

import requests

from flask import Blueprint, Response, request, send_file, abort
from flask_jsonpify import jsonpify

from sqlalchemy import create_engine, text

from .caching import add_cache_header

ROOT_DIR = Path(__file__).parent

class SimpleDBBlueprint(Blueprint):

TABLES = [
'budget_items_data',
'budget_topics_data',
'supports_data',
'contracts_data',
'entities_data',
'tenders_data'
]

DATAPACKAGE_URL = 'https://next.obudget.org/datapackages/simpledb'

def __init__(self, connection_string):
super().__init__('simpledb', 'simpledb')
self.connection_string = connection_string
self.tables = self.process_tables()
self.add_url_rule(
'/tables/<table>',
'table',
self.get_table,
methods=['GET']
)

self.add_url_rule(
'/tables',
'tables',
self.get_tables,
methods=['GET']
)

@contextmanager
def connect_db(self):
engine = create_engine(self.connection_string)
connection = engine.connect()
try:
yield connection
finally:
connection.close()
engine.dispose()
del engine

def process_tables(self):
ret = dict()
with self.connect_db() as connection:
for table in self.TABLES:
ret[table] = dict()
datapackage_url = f'{self.DATAPACKAGE_URL}/{table}/datapackage.json'
package_descriptor = requests.get(datapackage_url).json()
fields = package_descriptor['resources'][0]['schema']['fields']
ret['fields'] = [dict(
name=f['name'],
**f.get('details', {})
) for f in fields]
ret[table]['schema'] = self.get_schema(connection, table)
return ret

def get_schema(self, connection, table):
query = text(f"select generate_create_table_statement('{table}')")
result = connection.execute(query)
create_table = result.fetchone()[0]
return create_table

def get_table(self, table):
if table not in self.tables:
abort(404)
return jsonpify(self.tables[table])

def get_tables(self):
return jsonpify(list(self.tables.keys()))


def setup_simpledb(app):
sdb = SimpleDBBlueprint(os.environ['DATABASE_READONLY_URL'])
add_cache_header(sdb, 3600)
app.register_blueprint(sdb, url_prefix='/api/')

0 comments on commit 3545fc8

Please sign in to comment.