Skip to content

Commit

Permalink
Paul Vernon's "DB Library" of Views, functions, compound statements a…
Browse files Browse the repository at this point in the history
…nd other things (IBM#32)

* db-library version 1.0

* Update docs

* eclipse settings, WEB_INF directories and classpath file
  • Loading branch information
paul-vernon-ibm authored Feb 3, 2021
1 parent 1bf3753 commit 41d8895
Show file tree
Hide file tree
Showing 271 changed files with 44,303 additions and 0 deletions.
108 changes: 108 additions & 0 deletions db_library/README.md
Original file line number Diff line number Diff line change
@@ -0,0 +1,108 @@
# A Db2 Library

This library contains a set of hopefully useful of Db2 SQL views, functions and procedural code.

- **Views** to simplify working with Db2's system catalog and monitoring SQL functions.
- **Functions** to augment Db2's built-in ones
- **Compound statements** to run SQL against multiple objects
- **Procedures** to encapsulate some useful processes
- **Variables** to allow some views to be parameterized

You can use the files individually, or install the objects in a schema in your Db2 database(s).

There is a list and description of all objects here: [db-library.md](db-library.md)

## Install

Run [db-library.sql](db-library.sql) file in your favorite SQL interface.

> You will need to set the *statement delimiter* to `@` (i.e. do not use the default `;` delimiter).

By default the objects will be created in a schema called `DB`, but you can change that in the script.

All the objects are prefixed `DB_`, so you can add them to an existing schema if you wish

## Requirements

Db2 11.1 or upwards

For Db2 11.1, use the [db-library.db2_11.1.sql](db-library.db2_11.1.sql) file the


### Install via CLP

db2 -td@ -f db-library.sql

I recommend to *not* use the `db2` CLP as it strips all line-feeds from SQL VIEWs when it creates them.
This legacy behavior means that you loose all my nice formatting in the catalog which makes the view SQL less useful for reference.

### Install vis dbsql

dbsql -h $host -port $port -u $user -pw $password -d $database -terminator @ -f db-library.sql

### Uninstall

The [uninstall.sql](uninstall.sql) code will simply `DROP` all Views and Functions that begin with the three characters `DB_` in your **current schema**.

> Be careful, as this will drop any of *your* objects if they also start with the same three characters.

## Notes

The library has been created primarily while working on Db2 Warehouse, Db2 Warehouse on Cloud and IBM Integrated Analytics Systems.
It therefore has a certain focus on managing Column Organized Tables and Data Warehouse workloads.

It should still be useful for OLTP and mixed workloads, but feel free to suggest changes/additions to improve it's utility in this area.

The compound statements are particually useful when you don't have (or don't want to use) a shell or other scripting language for simple SQL tasks.
Often they are little more than wrappers to avoid the need to cut-and-paste "generated" SQL results back into your editor for execution.


The library is intended to be used from an **SQL GUI editor** rather than the Db2 command line processor.
For example, none of the views include `SUBSTR` on columns to reduce their display length.

The `@` is used as the statement delimiter is used throughout. It is needed for the compound SQL (i.e. `BEGIN` `END`) statements.

`@` is not a bad practice to get used to using in general as you can then use in-line atomic statements in your day-to-day SQL work.

The library only supports Db2 11.1 upwards due to the use of `REXEXP` functions. SOme thinks will work on DB2 10.5 or earlier, but this has not been tested.


The views use the same column names as the db2 SYSCAT catalog views for the most part.
So we use e.g. `TABSCHMEA`, `TABNAME`, `COLNAME` et al.
This makes it simpler to join the db views with catalog tables and monitoring functions, even though say `COLUMN` or `COLUMN_NAME` might have been a little more user friendly in result sets.

I hope to have been somewhat consistent with my use of abbreviations. E.g.

- Use `DB` not `DATABASE`
- USE `DBM` not `DATABASE_MANAGER`
- Use `GB` not `GIGABYTE` etc


I have tried to follow a certain SQL coding style for the views. This can be summarised as

- Use Unix line endings (i.e. `lF`, not `CR` `LF`)
- Use UTF-8 encoding
- Use spaces, not tabs to format the code
- Use 4 spaces as the indentation size
- Use start of line comma separators, not end of line
- All code in UPPER-CASE
- Vertically align code in many cases


We use the following options on all ATOMIC SQL scalar functions that are not using in-lined SQL

ALLOW PARALLEL -- The default is DISALLOW PARALLEL
DETERMINISTIC -- The default is NOT DETERMINISTIC which is not needed for most SQL UDFs
NO EXTERNAL ACTION -- The default is EXTERNAL ACTION which is not needed for most SQL UDFs


Finally, this library is far from perfect. It is provided AS-IS, however if you feel you can improve it,
please do send pulls requests for new or improved code.

## License

This code pattern is licensed under the Apache License, Version 2. Separate third-party code objects invoked within this code pattern are licensed by their respective providers pursuant to their own separate licenses. Contributions are subject to the [Developer Certificate of Origin, Version 1.1](https://developercertificate.org/) and the [Apache License, Version 2](https://www.apache.org/licenses/LICENSE-2.0.txt).

[Apache License FAQ](https://www.apache.org/foundation/license-faq.html#WhatDoesItMEAN)
171 changes: 171 additions & 0 deletions db_library/build.sh
Original file line number Diff line number Diff line change
@@ -0,0 +1,171 @@
#!/bin/bash

# A simple bit of code to concatenate all the library views and other CREATEable things into a single "install" sql file
# also creates a version of the views for use against snapshot versions of SYSCAT, SYSIBMADM and the MON table functions
# and generates the db-library.md file and comments.sql from the 5th line of each file

NAME="db-library"
echo $(($(cat version)+1)) > version
VERSION=$(cat version)
MAJOR=1

OUT=$NAME.sql
DOCS=db-library.md

echo creating $OUT for version $MAJOR.$VERSION

echo -n > $OUT

echo "--# (C) Copyright IBM Corp. 2020 All Rights Reserved." >> $OUT
echo "--# SPDX-License-Identifier: Apache-2.0" >> $OUT
echo '' >> $OUT
echo "--# db-library version $MAJOR.$VERSION" >> $OUT
echo '' >> $OUT
echo '/*' >> $OUT
cat known_issues.txt >> $OUT
echo '*/' >> $OUT

echo "SET SCHEMA DB @ -- You can install in any schema you like. DB is not a bad one to choose, but up to you " >> $OUT
echo "SET PATH=SYSTEM PATH,DB @ -- change it in the path too, if you do change it" >> $OUT
echo >> $OUT
echo "CREATE OR REPLACE VARIABLE DB_VERSION DECIMAL(6,3) DEFAULT $MAJOR.$VERSION @" >> $OUT
echo >> $OUT

cat $OUT > ${OUT/.sql/}.db2_11.1.sql

echo "--GRANT SELECTIN ON SCHEMA DB TO PUBLIC @ -- optional only supported in Db2 Warehouse currently" >> $OUT
echo >> $OUT

echo adding variables
for f in variables/*.sql
do
tail -n +3 $f >> $OUT
tail -n +3 $f >> ${OUT/.sql/}.db2_11.1.sql
done
echo "" >> $OUT

echo adding scalar_functions
for f in scalar_functions/*.sql
do
# echo "-- $f" >> $OUT
tail -n +3 $f >> $OUT
echo '' >> $OUT
echo '@' >> $OUT
tail -n +3 $f | sed -re 's/(\s+)(ALLOW PARALLEL)(\s*)/\1\/*\2*\/\3/g' | sed -re 's/(\/\*[1-9][1-9]\.[0-9]\.[0-9]\*\/)/--\1/g' >> ${OUT/.sql/}.db2_11.1.sql
echo '' >> ${OUT/.sql/}.db2_11.1.sql
echo '@' >> ${OUT/.sql/}.db2_11.1.sql
done

# List files in reverse order to allow
# some views to reference others with the same prefix

F=$(ls -1 -r views/*.sql)
for f in $F
do
tail -n +3 $f >> $OUT
echo '' >> $OUT
echo '@' >> $OUT
if [ ! "${f#views/}" = "db_external_tables.sql" ]; then
tail -n +3 $f | sed -re 's/(\/\*[1-9][1-9]\.[0-9]\.[0-9]\*\/)/--\1/g' >> ${OUT/.sql/}.db2_11.1.sql
echo '' >> ${OUT/.sql/}.db2_11.1.sql
echo '@' >> ${OUT/.sql/}.db2_11.1.sql
fi
done



# build the comments by taking the 5th line of each file and putting them into a COMMENT ON statement
cat /dev/null > comments.sql
cd views
for f in *.sql
do
t=${f%.sql}
c=$(tail -n +5 $f | head -1 | cut -b 4- | sed -re "s/'/''/")
echo "COMMENT ON TABLE ${t^^} IS '$c' @" >> ../comments.sql
done
cd ../scalar_functions
for f in *.sql
do
t=${f%.sql}
c=$(tail -n +5 $f | head -1 | cut -b 4- | sed -re "s/'/''/")
echo "COMMENT ON FUNCTION ${t^^} IS '$c' @" >> ../comments.sql
done
cd ..
echo "
COMMENT ON VARIABLE DB_DIAG_FROM_TIMESTAMP IS 'Limits rows returned in DB_DIAG to entries more recent than this value' @
COMMENT ON VARIABLE DB_DIAG_TO_TIMESTAMP IS 'Limits rows returned in DB_DIAG to entries older than this value' @
COMMENT ON VARIABLE DB_DIAG_MEMBER IS 'Limits rows returned in DB_DIAG to entries from this member. -1 = current member. -2 = all members' @
" >> comments.sql

# add the comments
cat comments.sql >> $OUT
cat comments.sql | sed -re 's/^(COMMENT ON TABLE DB_EXTERNAL_TABLES)/--\1/g' >> ${OUT/.sql/}.db2_11.1.sql
rm comments.sql

# now cat dbx_procs such as dbx_uninstall

# build a version of the views that will run against tables in the current schema named the same as the catalog views and mon functions
cat $OUT | sed -re 's/((SYSCAT|SYSIBMADM|SYSTOOLS))\./\/*\1*\//ig' | sed -re 's/(TABLE\()(((MON)|(ADMIN))[A-Z\_]*)\s*(\(.*?\)?\))/\/*\1*\/\2\/*\6*\//ig' > ${OUT/.sql/}.snapshot.sql
cat ${OUT/.sql/}.db2_11.1.sql | sed -re 's/((SYSCAT|SYSIBMADM|SYSTOOLS))\./\/*\1*\//ig' | sed -re 's/(TABLE\()(((MON)|(ADMIN))[A-Z\_]*)\s*(\(.*?\)?\))/\/*\1*\/\2\/*\6*\//ig' > ${OUT/.sql/}.snapshot.db2_11.1.sql

## override the couple of views that need to be coded differently to get OK performance from the snapshot tables
for f in offline/*/*.sql
do
cat $f >> ${OUT/.sql/}.snapshot.sql
cat $f >> ${OUT/.sql/}.snapshot.db2_11.1.sql
done

## Now build the docs by again taking the 5th line

echo "
# db-library
- [Compound Statements](#compound_statements)
- [Procedures](#procedures)
- [Functions](#functions)
- [Views](#views)
- [DB2 Catalog Poster](images/db2-syscat-11.5.2.0.png)
- [DB2 WLM Poster](images/db2-wlm-syscat-11.5.4.0.png)
[Readme](README.md)
" > ${DOCS}

echo -n "
## [Compound Statements](compound_statements)
| Compound Statement | Description
| ------------ | -------------
" >> $DOCS
cd compound_statements
for f in *.sql; do echo -n "|[${f%.sql}](compound_statements/$f)|"; echo -n "$(head -n 5 $f | tail -1 | cut -b 4-150)"; echo "|" ; done >> ../${DOCS}
cd ..
echo -n "
## [Procedures](procedures)
| Procedures | Description
| ----------- | -------------
" >> ${DOCS}
cd procedures
for f in *.sql; do echo -n "|[${f%.sql}](procedures/$f)|"; echo -n "$(head -n 5 $f | tail -1 | cut -b 4-150)"; echo "|" ; done >> ../${DOCS}
cd ..
echo >> ${DOCS}
echo -n "
## [Functions](scalar_functions)
| Function | Description
| ------------ | -------------
" >> ${DOCS}
cd scalar_functions
for f in *.sql; do echo -n "|[${f%.sql}](scalar_functions/$f)|"; echo -n "$(head -n 5 $f | tail -1 | cut -b 4-150)"; echo "|" ; done >> ../${DOCS}
cd ..

echo >> ${DOCS}
echo -n "
## [Views](views)
| View | Description
| ------------ | -------------
" >> ${DOCS}
cd views
for f in *.sql; do echo -n "|[${f%.sql}](views/$f)|"; echo -n "$(head -n 5 $f | tail -1 | cut -b 4-150)"; echo "|" ; done >> ../${DOCS}
cd ..

23 changes: 23 additions & 0 deletions db_library/compound_statements/add_range_partitions.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,23 @@
--# Copyright IBM Corp. All Rights Reserved.
--# SPDX-License-Identifier: Apache-2.0

/*
* Add multiple range partitions in one statement
*
* Db2 does not allow you to use e.g. EVERY x DAYS when ALTERing a range partition table to add new ranges
*
* This is an example of using a compound statement to add multiple range partitions to the following table
*
* CREATE TABLE RP(i INT, d DATE) ORGANIZE BY ROW PARTITION BY RANGE ( d ) ( STARTING FROM '2020-11-01' ENDING AT '2021-01-01' EXCLUSIVE EVERY 1 DAYS )
*
*/
BEGIN
DECLARE D DATE DEFAULT '2021-01-01';
--
WHILE D < '2021-02-01'
DO
EXECUTE IMMEDIATE 'ALTER TABLE RP ADD PARTITION ENDING(''' || D || ''')' ;
SET D = D + 1 DAY;
END WHILE;
END
@
29 changes: 29 additions & 0 deletions db_library/compound_statements/alter_column_set_default.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
--# Copyright IBM Corp. All Rights Reserved.
--# SPDX-License-Identifier: Apache-2.0

/*
* Add a DEFAULT clause to every column in the tables selected
*/
BEGIN
FOR C AS cur CURSOR WITH HOLD FOR
SELECT 'ALTER TABLE "' || RTRIM(TABSCHEMA) || '"."' || TABNAME || '"'
|| ' ALTER COLUMN "' || COLNAME || '"'
|| ' SET DEFAULT'
AS S1
FROM SYSCAT.TABLES T JOIN SYSCAT.COLUMNS C USING (TABSCHEMA, TABNAME)
WHERE T.TYPE = 'T'
AND T.TEMPORALTYPE = 'N' -- exclude temportal tables
AND C.DEFAULT IS NULL
AND C.KEYSEQ IS NULL -- exclude PK columns
AND C.IDENTITY = 'N' -- exclude identity columns
AND C.GENERATED = '' -- exclude generated columns
AND T.TABSCHEMA = 'your schema'
ORDER BY
TABSCHEMA
, TABNAME
WITH UR
DO
EXECUTE IMMEDIATE C.S1;
-- COMMIT; -- skip the commit to make it run faster ?
END FOR;
END
29 changes: 29 additions & 0 deletions db_library/compound_statements/alter_fk_not_trusted.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,29 @@
--# Copyright IBM Corp. All Rights Reserved.
--# SPDX-License-Identifier: Apache-2.0

/*
* For every TRUSTED FORIEGN KEY, ALTER it to be NOT TRUSTED
*
* A more intelligent version of this script would only set FKs to NOT TRUSTED if they are indeed not true...
*
*/

BEGIN
FOR C AS cur CURSOR WITH HOLD FOR
SELECT
'ALTER TABLE "' || TABSCHEMA || '"."' || TABNAME || '" ALTER FOREIGN KEY "' || CONSTNAME || '"'
|| ' NOT ENFORCED NOT TRUSTED' AS ALTER_FK
FROM
SYSCAT.TABCONST C
WHERE
C.TYPE = 'F'
AND C.ENFORCED = 'N'
AND C.TRUSTED = 'Y'
AND SUBSTR(C.TABSCHEMA,1,3) NOT IN ('SYS','IBM','DB2')
AND TABSCHEMA = 'YOUR_SCHEMA'
WITH UR
DO
EXECUTE IMMEDIATE C.ALTER_FK;
COMMIT;
END FOR;
END
Loading

0 comments on commit 41d8895

Please sign in to comment.