Skip to content

Commit

Permalink
Add materialized view support (#78)
Browse files Browse the repository at this point in the history
* Add materialized view support

* Add support for comments
  • Loading branch information
dcarneir authored Nov 18, 2024
1 parent b6c00ff commit 803bbf7
Show file tree
Hide file tree
Showing 17 changed files with 616 additions and 107 deletions.

Large diffs are not rendered by default.

Original file line number Diff line number Diff line change
Expand Up @@ -35,6 +35,9 @@ package br.com.bluesoft.bee.database.reader
import br.com.bluesoft.bee.model.Constraint
import br.com.bluesoft.bee.model.Index
import br.com.bluesoft.bee.model.IndexColumn
import br.com.bluesoft.bee.model.MView
import br.com.bluesoft.bee.model.MViewIndex
import br.com.bluesoft.bee.model.MViewIndexColumn
import br.com.bluesoft.bee.model.Procedure
import br.com.bluesoft.bee.model.Schema
import br.com.bluesoft.bee.model.Sequence
Expand All @@ -58,6 +61,7 @@ class PostgresDatabaseReader implements DatabaseReader {
schema.tables = getTables(objectName, schema.databaseVersion)
schema.sequences = getSequences(objectName)
schema.views = getViews(objectName)
schema.mviews = getMViews(objectName)
schema.procedures = getProcedures(objectName)
schema.packages = getPackages(objectName)
schema.triggers = getTriggers(objectName)
Expand Down Expand Up @@ -85,15 +89,17 @@ class PostgresDatabaseReader implements DatabaseReader {
}

static final def TABLES_QUERY = '''
select t.table_name, 'N'as temporary
from information_schema.tables t
where t.table_type = 'BASE TABLE' and table_schema not in ('pg_catalog', 'information_schema')
select t.table_name, 'N'as temporary, description
from information_schema.tables t
left join pg_description d on d.objoid = to_regclass(t.table_name)::regclass::oid
where t.table_type = 'BASE TABLE' and table_schema not in ('pg_catalog', 'information_schema')
order by table_name
'''
static final def TABLES_QUERY_BY_NAME = '''
select t.table_name, 'N'as temporary
from information_schema.tables t
where t.table_type = 'BASE TABLE' and table_schema not in ('pg_catalog', 'information_schema')
select t.table_name, 'N'as temporary, description
from information_schema.tables t
left join pg_description d on d.objoid = to_regclass(t.table_name)::regclass::oid
where t.table_type = 'BASE TABLE' and table_schema not in ('pg_catalog', 'information_schema')
and t.table_name = ?
order by table_name
'''
Expand All @@ -109,7 +115,7 @@ class PostgresDatabaseReader implements DatabaseReader {
rows.each({
def name = it.table_name.toLowerCase()
def temporary = it.temporary == 'Y' ? true : false
def comment = ''
def comment = it.description
tables[name] = new Table(name: name, temporary: temporary, comment: comment)
})
return tables
Expand All @@ -126,12 +132,13 @@ class PostgresDatabaseReader implements DatabaseReader {
else 0
end
as data_size, is_generated,
ic.numeric_scale as data_scale, coalesce(ic.column_default, ic.generation_expression) as data_default
ic.numeric_scale as data_scale, coalesce(ic.column_default, ic.generation_expression) as data_default,
col_description(to_regclass(it.table_name)::regclass::oid, ic.ordinal_position) as comments
from information_schema.columns ic
inner join information_schema.tables it on it.table_name = ic.table_name
where ic.table_schema not in ('pg_catalog' , 'information_schema')
and it.table_type = 'BASE TABLE\'
order by ic.table_name, ic.ordinal_position;
and it.table_type = 'BASE TABLE'
order by ic.table_name, ic.ordinal_position
'''

static final def TABLES_COLUMNS_QUERY_BY_NAME = '''
Expand All @@ -144,13 +151,14 @@ class PostgresDatabaseReader implements DatabaseReader {
else 0
end
as data_size, is_generated,
ic.numeric_scale as data_scale, coalesce(ic.column_default, ic.generation_expression) as data_default
ic.numeric_scale as data_scale, coalesce(ic.column_default, ic.generation_expression) as data_default,
col_description(to_regclass(it.table_name)::regclass::oid, ic.ordinal_position) as comments
from information_schema.columns ic
inner join information_schema.tables it on it.table_name = ic.table_name
where ic.table_schema not in ('pg_catalog' , 'information_schema')
and it.table_type = 'BASE TABLE\'
and it.table_type = 'BASE TABLE'
and ic.table_name = ?
order by ic.table_name, ic.ordinal_position;
order by ic.table_name, ic.ordinal_position
'''

private def fillColumns(tables, objectName) {
Expand All @@ -169,6 +177,7 @@ class PostgresDatabaseReader implements DatabaseReader {
column.scale = it.data_scale == null ? 0 : it.data_scale
column.nullable = it.nullable == 'NO' ? false : true
column.virtual = it.is_generated == 'ALWAYS'
column.comment = it.comments
def defaultValue = it.data_default
if (defaultValue) {
column.defaultValue = defaultValue?.trim()?.toUpperCase() == 'NULL' ? null : defaultValue?.trim()
Expand Down Expand Up @@ -200,8 +209,10 @@ class PostgresDatabaseReader implements DatabaseReader {
join pg_namespace ns on ct.relnamespace = ns.oid
join pg_am am on (ci.relam = am.oid)
left join information_schema.table_constraints tc on (ns.nspname = tc.constraint_schema and ci.relname = tc.constraint_name)
left join pg_matviews mv on (ns.nspname = mv.schemaname and ct.relname = mv.matviewname)
where ns.nspname not in ('information_schema', 'pg_catalog', 'pg_toast')
and tc.constraint_name is null
and mv.matviewname is null
) t
order by table_name, index_name, n
'''
Expand All @@ -219,11 +230,13 @@ class PostgresDatabaseReader implements DatabaseReader {
join pg_namespace ns on ct.relnamespace = ns.oid
join pg_am am on (ci.relam = am.oid)
left join information_schema.table_constraints tc on (ns.nspname = tc.constraint_schema and ci.relname = tc.constraint_name)
left join pg_matviews mv on (ns.nspname = mv.schemaname and ct.relname = mv.matviewname)
where ns.nspname not in ('information_schema', 'pg_catalog', 'pg_toast')
and tc.constraint_name is null
and mv.matviewname is null
and ct.relname = ?
) t
order by table_name, index_name, n
order by table_name, index_name, n
'''

private def fillIndexes(tables, objectName, databaseVersion) {
Expand Down Expand Up @@ -466,6 +479,107 @@ class PostgresDatabaseReader implements DatabaseReader {
return views
}

def getMViews(objectName) {
def mviews = fillMViews(objectName)
fillMViewsIndexes(mviews, objectName)
return mviews
}

final static def MVIEW_QUERY = "select matviewname as mview_name, definition as query from pg_matviews"
final static def MVIEW_QUERY_BY_NAME = "select matviewname as mview_name, definition as query from pg_matviews where matviewname = lower(?)"

private def fillMViews(objectName) {
def mviews = [:]
def rows
if (objectName) {
rows = sql.rows(MVIEW_QUERY_BY_NAME, [objectName])
} else {
rows = sql.rows(MVIEW_QUERY)
}

rows.each({
def mview = new MView()
mview.name = it.mview_name.toLowerCase()
mview.text_postgres = it.query
mviews[mview.name] = mview
})
return mviews
}

final static def MVIEW_INDEXES_QUERY = '''
select schemaname, table_name, index_name, uniqueness, index_type,
pg_get_indexdef(coid, n, false) as column_name, pg_get_indexdef(coid, 0, false) definition,
case when pg_index_column_has_property(coid,n, 'asc') then 'asc' else 'desc' end as descend
from (
select ns.nspname schemaname, ct.relname as table_name, ci.relname as index_name, i.indisunique as uniqueness, am.amname index_type,
generate_series(1, i.indnatts) n, ci.oid coid
from pg_index i
join pg_class ct on i.indrelid = ct.oid
join pg_class ci on i.indexrelid = ci.oid
join pg_namespace ns on ct.relnamespace = ns.oid
join pg_am am on (ci.relam = am.oid)
left join information_schema.table_constraints tc on (ns.nspname = tc.constraint_schema and ci.relname = tc.constraint_name)
join pg_matviews mv on (ns.nspname = mv.schemaname and ct.relname = mv.matviewname)
where ns.nspname not in ('information_schema', 'pg_catalog', 'pg_toast')
and tc.constraint_name is null
) t
order by table_name, index_name, n
'''
final static def MVIEW_INDEXES_QUERY_BY_NAME = '''
select schemaname, table_name, index_name, uniqueness, index_type,
pg_get_indexdef(coid, n, false) as column_name, pg_get_indexdef(coid, 0, false) definition,
case when pg_index_column_has_property(coid,n, 'asc') then 'asc' else 'desc' end as descend
from (
select ns.nspname schemaname, ct.relname as table_name, ci.relname as index_name, i.indisunique as uniqueness, am.amname index_type,
generate_series(1, i.indnatts) n, ci.oid coid
from pg_index i
join pg_class ct on i.indrelid = ct.oid
join pg_class ci on i.indexrelid = ci.oid
join pg_namespace ns on ct.relnamespace = ns.oid
join pg_am am on (ci.relam = am.oid)
left join information_schema.table_constraints tc on (ns.nspname = tc.constraint_schema and ci.relname = tc.constraint_name)
join pg_matviews mv on (ns.nspname = mv.schemaname and ct.relname = mv.matviewname)
where ns.nspname not in ('information_schema', 'pg_catalog', 'pg_toast')
and tc.constraint_name is null
and ct.relname = lower(?)
) t
order by table_name, index_name, n
'''

private def fillMViewsIndexes(mviews, objectName) {
def rows
if (objectName) {
rows = sql.rows(MVIEW_INDEXES_QUERY_BY_NAME, [objectName])
} else {
rows = sql.rows(MVIEW_INDEXES_QUERY)
}

rows.each({
def name = it.table_name.toLowerCase()
def mview = mviews[name]
def indexName = it.index_name.toLowerCase()
if (mview) {
def indexAlreadyExists = mview.indexes[indexName] ? true : false
def index = null;
if (indexAlreadyExists) {
index = mview.indexes[indexName]
} else {
index = new MViewIndex()
index.name = indexName
index.type = getIndexType(it.index_type)
index.unique = it.uniqueness
def parts = (it.definition as String).split('\\) WHERE ')
index.where = parts.size() > 1 ? parts[1] : null
mview.indexes[index.name] = index
}
def indexColumn = new MViewIndexColumn()
indexColumn.name = it.column_name.toLowerCase()
indexColumn.descend = it.descend.toLowerCase() == 'desc' ? true : false
index.columns << indexColumn
}
})
}

final static def PROCEDURES_NAME_QUERY = '''
select distinct n.nspname, p.proname as name
from pg_namespace n
Expand Down
Original file line number Diff line number Diff line change
Expand Up @@ -53,34 +53,38 @@ class RedshiftDatabaseReader implements DatabaseReader {
static final def TABLES_QUERY = '''
select n.nspname as schemaname, c.relname as table_name,
case releffectivediststyle
when 0 then 'even'
when 1 then 'key distkey(' || max(case when distkey then "column" end) || ')'
when 8 then 'all'
end as dist_style
when 0 then 'even\'
when 1 then 'key distkey(' || max(case when distkey then "column" end) || ')\'
when 8 then 'all\'
end as dist_style,
cd.description as comment
from pg_namespace n
join pg_class c on n.oid = c.relnamespace and c.relkind = 'r'
join pg_class_info i on c.oid = i.reloid
join pg_table_def d on n.nspname = d.schemaname and c.relname = d.tablename
left join pg_description cd on cd.objoid = c.oid
where schemaname not in ('pg_catalog', 'information_schema')
and pg_table_is_visible(c.oid)
group by n.nspname, c.relname, releffectivediststyle
group by n.nspname, c.relname, releffectivediststyle, cd.description
order by n.nspname, c.relname
'''
static final def TABLES_QUERY_BY_NAME = '''
select n.nspname as schemaname, c.relname as table_name,
case releffectivediststyle
when 0 then 'even'
when 1 then 'key distkey(' || max(case when distkey then "column" end) || ')'
when 8 then 'all'
end as dist_style
when 0 then 'even\'
when 1 then 'key distkey(' || max(case when distkey then "column" end) || ')\'
when 8 then 'all\'
end as dist_style,
cd.description as comment
from pg_namespace n
join pg_class c on n.oid = c.relnamespace and c.relkind = 'r'
join pg_class_info i on c.oid = i.reloid
join pg_table_def d on n.nspname = d.schemaname and c.relname = d.tablename
left join pg_description cd on cd.objoid = c.oid
where schemaname not in ('pg_catalog', 'information_schema')
and pg_table_is_visible(c.oid)
and tablename = ?
group by n.nspname, c.relname, releffectivediststyle
group by n.nspname, c.relname, releffectivediststyle, cd.description
order by n.nspname, c.relname
'''

Expand All @@ -94,7 +98,7 @@ class RedshiftDatabaseReader implements DatabaseReader {
}
rows.each({
def name = it.table_name.toLowerCase()
def comment = ''
def comment = it.comment
tables[name] = new Table(name: name, temporary: false, comment: comment, distStyle: it.dist_style)
})
return tables
Expand All @@ -110,6 +114,7 @@ class RedshiftDatabaseReader implements DatabaseReader {
, false is_generated
, ad.adsrc::information_schema.character_data data_default
, a.attsortkeyord
, col_description(c.oid, a.attnum) as comment
from pg_namespace n
join pg_class c on n.oid = c.relnamespace and c.relkind = 'r'
join pg_attribute a on c.oid = a.attrelid
Expand All @@ -131,6 +136,7 @@ class RedshiftDatabaseReader implements DatabaseReader {
, false is_generated
, ad.adsrc::information_schema.character_data data_default
, a.attsortkeyord
, col_description(c.oid, a.attnum) as comment
from pg_namespace n
join pg_class c on n.oid = c.relnamespace and c.relkind = 'r'
join pg_attribute a on c.oid = a.attrelid
Expand Down Expand Up @@ -164,6 +170,7 @@ class RedshiftDatabaseReader implements DatabaseReader {
column.nullable = it.nullable
column.virtual = it.is_generated
column.sortKeyOrder = it.attsortkeyord
column.comment = it.comment
def defaultValue = it.data_default
if (defaultValue) {
column.defaultValue = defaultValue?.trim()?.toUpperCase() == 'NULL' ? null : defaultValue?.trim()
Expand Down
11 changes: 11 additions & 0 deletions src/main/groovy/br/com/bluesoft/bee/exporter/JsonExporter.groovy
Original file line number Diff line number Diff line change
Expand Up @@ -49,6 +49,7 @@ public class JsonExporter implements Exporter {
File proceduresFolder
File packagesFolder
File triggersFolder
File mviewsFolder
File userTypesFolder

JsonExporter(Schema schema) {
Expand Down Expand Up @@ -83,6 +84,9 @@ public class JsonExporter implements Exporter {
triggersFolder = new File(mainFolder, 'triggers')
triggersFolder.mkdir()

mviewsFolder = new File(mainFolder, 'mviews')
mviewsFolder.mkdir()

userTypesFolder = new File(mainFolder, 'usertypes')
userTypesFolder.mkdir()

Expand All @@ -96,6 +100,7 @@ public class JsonExporter implements Exporter {
createProceduresFiles(schema.getProcedures())
createPackagesFiles(schema.getPackages())
createTriggersFiles(schema.getTriggers())
createMViewFiles(schema.getMviews())
createUserTypesFiles(schema.getUserTypes())
}

Expand Down Expand Up @@ -135,6 +140,12 @@ public class JsonExporter implements Exporter {
}
}

void createMViewFiles(def mviews) {
mviews.each {
mapper.writeValue(new File(mviewsFolder, "${it.value.name}.bee"), it.value)
}
}

void createUserTypesFiles(def userTypes) {
userTypes.each { name, userType ->
mapper.writeValue(new File(userTypesFolder, "${name}.bee"), userType)
Expand Down
Loading

0 comments on commit 803bbf7

Please sign in to comment.