diff --git a/examples/tap/tap_schema/migration_1.1.sql b/examples/tap/tap_schema/migration_1.1.sql new file mode 100644 index 0000000000000000000000000000000000000000..1f11dfa2c63e64e6525be2b8db6ec1bcf210b4c2 --- /dev/null +++ b/examples/tap/tap_schema/migration_1.1.sql @@ -0,0 +1,110 @@ +-- SQL Script based on TAP 1.1 (http://www.ivoa.net/documents/TAP/20160428/WD-TAP-1.1-20160428.pdf) +-- +-- DESCRIPTION: +-- This script aims to migrate from a TAP_SCHEMA already existing into a TAP_SCHEMA as described +-- by the IVOA in the version 1.1 of the TAP standard. +-- +-- This script is executed using 3 distinct and successive transactions: one for the step 0, +-- another one for the step 1 (actually managed by the script tap_schema_1.1.sql) and a last +-- one for the rest of the script. +-- +-- WARNING 1: FORMER TAP_SCHEMA NOT DESTROYED +-- This SQL script does not destroy the former TAP_SCHEMA ; it is just renaming it into "old_TAP_SCHEMA". +-- It is particularly useful if you had added non-standard tables and/or columns. Thus, all former information +-- are still stored somewhere so that you can import them again with your own SQL script. + +-- If you however want the former TAP_SCHEMA to be destroyed, just uncomment the last instruction of this SQL script: +-- the step 5 (i.e. the DROP SCHEMA ... CASCADE). +-- +-- WARNING 2: SPECIAL COLUMN "DBNAME" +-- The special column "dbname" is expected in TAP_SCHEMA.schemas, TAP_SCHEMA.tables and TAP_SCHEMA.columns. +-- It is a column possibly expected by the TAP Library in order to perform an easy matching between ADQL names +-- and DB names during the ADQL to SQL translation. It allows to have different schema, table and/or column +-- name in ADQL/TAP than in the real database. +-- +-- If your TAP_SCHEMA does not already have this column, you must uncomment the 3 commented lines of the step +-- 2 of this script. +-- +-- NOTE: +-- Tested and designed for PostgreSQL ; it may work with some modifications for other DBMS +-- +-- AUTHOR: Grégory Mantelet (ARI) +-- DATE : July 2016 + + +BEGIN; + +-- 0. CHANGE THE SCHEMA NAME OF TAP_SCHEMA 1.0: + +ALTER SCHEMA "TAP_SCHEMA" RENAME TO "old_TAP_SCHEMA"; + +-- 0bis. FIX SOME POSSIBLE PROBLEM WITH NULL VALUES: + +UPDATE "old_TAP_SCHEMA"."tables" SET table_type = 'table' + WHERE table_type IS NULL; + +UPDATE "old_TAP_SCHEMA"."columns" SET indexed = 0 + WHERE indexed IS NULL; + +UPDATE "old_TAP_SCHEMA"."columns" SET principal = 0 + WHERE principal IS NULL; + +UPDATE "old_TAP_SCHEMA"."columns" SET std = 0 + WHERE std IS NULL; + +COMMIT; + +-- 1. CREATE TAP_SCHEMA IN VERSION 1.1: + +\i tap_schema_1.1.sql + +BEGIN; + +-- 2. ADD THE SPECIAL COLUMN 'dbname' POSSIBLY USED BY THE TAP LIBRARY: + +--ALTER TABLE "old_TAP_SCHEMA"."schemas" ADD COLUMN "dbname" VARCHAR; +--ALTER TABLE "old_TAP_SCHEMA"."tables" ADD COLUMN "dbname" VARCHAR; +--ALTER TABLE "old_TAP_SCHEMA"."columns" ADD COLUMN "dbname" VARCHAR; + +ALTER TABLE "TAP_SCHEMA"."schemas" ADD COLUMN "dbname" VARCHAR; +ALTER TABLE "TAP_SCHEMA"."tables" ADD COLUMN "dbname" VARCHAR; +ALTER TABLE "TAP_SCHEMA"."columns" ADD COLUMN "dbname" VARCHAR; + +-- 3. FILL THE NEW TAP_SCHEMA WITH THE FORMER VALUES (except those of TAP_SCHEMA): + +INSERT INTO "TAP_SCHEMA"."schemas" + (SELECT * + FROM "old_TAP_SCHEMA"."schemas" + WHERE LOWER("schema_name") <> 'tap_schema'); + +INSERT INTO "TAP_SCHEMA"."tables" + (SELECT schema_name, table_name, table_type, description, utype, -1 AS "table_index", dbname + FROM "old_TAP_SCHEMA"."tables" + WHERE LOWER("schema_name") <> 'tap_schema'); + +INSERT INTO "TAP_SCHEMA"."columns" + (SELECT table_name, column_name, datatype, "size" AS "arraysize", "size", c.description, c.utype, unit, ucd, indexed, principal, std, -1 AS "column_index", c.dbname + FROM "old_TAP_SCHEMA"."columns" c JOIN "old_TAP_SCHEMA"."tables" USING("table_name") + WHERE LOWER("schema_name") <> 'tap_schema'); + +INSERT INTO "TAP_SCHEMA"."keys" + (SELECT * + FROM "old_TAP_SCHEMA"."keys"); + +INSERT INTO "TAP_SCHEMA"."key_columns" + (SELECT * + FROM "old_TAP_SCHEMA"."key_columns"); + +-- 4. CHANGE THE table_index of TAP_SCHEMA tables so that they are at the end when ordering by ascending table_index: + +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-5 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('schemas', 'tap_schema.schemas'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-4 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('tables', 'tap_schema.tables'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-3 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('columns', 'tap_schema.columns'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-2 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('keys', 'tap_schema.keys'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-1 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('key_columns', 'tap_schema.key_columns'); + +-- 5. REMOVE THE FORMER TAP_SCHEMA: + +--DROP SCHEMA "old_TAP_SCHEMA" CASCADE; + +COMMIT; diff --git a/examples/tap/tap_schema/tap_schema_1.0.sql b/examples/tap/tap_schema/tap_schema_1.0.sql new file mode 100644 index 0000000000000000000000000000000000000000..f1e9f643d6b319552f6091248668b2ad22a211c4 --- /dev/null +++ b/examples/tap/tap_schema/tap_schema_1.0.sql @@ -0,0 +1,77 @@ +-- SQL Script based on TAP 1.0 (http://www.ivoa.net/Documents/TAP/20100327/REC-TAP-1.0.pdf) +-- +-- DESCRIPTION: +-- This script create the schema TAP_SCHEMA and all its standard tables, as defined by the TAP standard +-- in the version 1.0. +-- +-- The whole script is executed in a transaction in order to avoid partial creation of TAP_SCHEMA +-- in case of an SQL error. +-- +-- NOTE: +-- Tested and designed for PostgreSQL ; it may work with some modifications for other DBMS +-- +-- AUTHOR: Grégory Mantelet (ARI) +-- DATE : July 2016 + + +BEGIN; + +-- 0. CREATE SCHEMA TAP_SCHEMA + +CREATE SCHEMA "TAP_SCHEMA"; + +-- 1. CREATE TABLES TAP_SCHEMA.* + +CREATE TABLE "TAP_SCHEMA"."schemas" ("schema_name" VARCHAR PRIMARY KEY, "description" VARCHAR , "utype" VARCHAR); +CREATE TABLE "TAP_SCHEMA"."tables" ("schema_name" VARCHAR , "table_name" VARCHAR PRIMARY KEY, "table_type" VARCHAR , "description" VARCHAR, "utype" VARCHAR, PRIMARY KEY("table_name")); +CREATE TABLE "TAP_SCHEMA"."columns" ("table_name" VARCHAR , "column_name" VARCHAR , "description" VARCHAR , "unit" VARCHAR , "ucd" VARCHAR , "utype" VARCHAR, "datatype" VARCHAR, "size" INTEGER, "principal" SMALLINT CHECK("principal" BETWEEN 0 AND 1), "indexed" SMALLINT CHECK("indexed" BETWEEN 0 AND 1), "std" SMALLINT CHECK("std" BETWEEN 0 AND 1), PRIMARY KEY("table_name","column_name")); +CREATE TABLE "TAP_SCHEMA"."keys" ("key_id" VARCHAR PRIMARY KEY , "from_table" VARCHAR , "target_table" VARCHAR , "description" VARCHAR, "utype" VARCHAR); +CREATE TABLE "TAP_SCHEMA"."key_columns" ("key_id" VARCHAR , "from_column" VARCHAR , "target_column" VARCHAR, PRIMARY KEY("key_id", "from_column", "target_column")); + +-- 2. FILL TAP_SCHEMA.schemas + +INSERT INTO "TAP_SCHEMA"."schemas" VALUES ('TAP_SCHEMA', 'Set of tables listing and describing the schemas, tables and columns published in this TAP service.', NULL); + +-- 2bis. FILL TAP_SCHEMA.tables + +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.schemas' , 'table', 'List of schemas published in this TAP service.' , NULL); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.tables' , 'table', 'List of tables published in this TAP service.' , NULL); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.columns' , 'table', 'List of columns of all tables listed in TAP_SCHEMA.TABLES and published in this TAP service.' , NULL); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.keys' , 'table', 'List all foreign keys but provides just the tables linked by the foreign key. To know which columns of these tables are linked, see in TAP_SCHEMA.key_columns using the key_id.', NULL); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.key_columns', 'table', 'List all foreign keys but provides just the columns linked by the foreign key. To know the table of these columns, see in TAP_SCHEMA.keys using the key_id.' , NULL); + +-- 2ter. FILL TAP_SCHEMA.columns + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.schemas', 'schema_name', 'schema name, possibly qualified' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.schemas', 'description', 'brief description of schema' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.schemas', 'utype' , 'UTYPE if schema corresponds to a data model', NULL, NULL, NULL, 'VARCHAR', -1, 0, 0, 1); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'schema_name', 'the schema name from TAP_SCHEMA.schemas' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'table_name' , 'table name as it should be used in queries', NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'table_type' , 'one of: table, view' , NULL, NULL, NULL, 'VARCHAR', -1, 0, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'description', 'brief description of table' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'utype' , 'UTYPE if table corresponds to a data model', NULL, NULL, NULL, 'VARCHAR', -1, 0, 0, 1); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'table_name' , 'table name from TAP_SCHEMA.tables' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'column_name', 'column name' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'description', 'brief description of column' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'unit' , 'unit in VO standard format' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'ucd' , 'UCD of column if any' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'utype' , 'UTYPE of column if any' , NULL, NULL, NULL, 'VARCHAR', -1, 0, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'datatype' , 'ADQL datatype as in section 2.5' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'size' , 'length of variable length datatypes' , NULL, NULL, NULL, 'INTEGER', -1, 0, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'principal' , 'a principal column; 1 means true, 0 means false', NULL, NULL, NULL, 'INTEGER', -1, 0, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'indexed' , 'an indexed column; 1 means true, 0 means false' , NULL, NULL, NULL, 'INTEGER', -1, 0, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'std' , 'a standard column; 1 means true, 0 means false' , NULL, NULL, NULL, 'INTEGER', -1, 0, 0, 1); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'key_id' , 'unique key identifier' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'from_table' , 'fully qualified table name', NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'target_table', 'fully qualified table name', NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'description' , 'description of this key' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 0, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'utype' , 'utype of this key' , NULL, NULL, NULL, 'VARCHAR', -1, 0, 0, 1); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.key_columns', 'key_id' , 'unique key identifier' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.key_columns', 'from_column' , 'key column name in the from_table' , NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.key_columns', 'target_column', 'key column name in the target_table', NULL, NULL, NULL, 'VARCHAR', -1, 1, 1, 1); + +COMMIT; diff --git a/examples/tap/tap_schema/tap_schema_1.1.sql b/examples/tap/tap_schema/tap_schema_1.1.sql new file mode 100644 index 0000000000000000000000000000000000000000..e220aa6bb0b93dcf09636384d9fbdd498c7d9b63 --- /dev/null +++ b/examples/tap/tap_schema/tap_schema_1.1.sql @@ -0,0 +1,83 @@ +-- SQL Script based on TAP 1.1 (http://www.ivoa.net/documents/TAP/20160428/WD-TAP-1.1-20160428.pdf) +-- +-- DESCRIPTION: +-- This script create the schema TAP_SCHEMA and all its standard tables, as defined by the TAP standard +-- in the version 1.1. +-- +-- The whole script is executed in a transaction in order to avoid partial creation of TAP_SCHEMA +-- in case of an SQL error. +-- +-- NOTE: +-- Tested and designed for PostgreSQL ; it may work with some modifications for other DBMS +-- +-- AUTHOR: Grégory Mantelet (ARI) +-- DATE : July 2016 + + +BEGIN; + +-- 0. CREATE SCHEMA TAP_SCHEMA + +CREATE SCHEMA "TAP_SCHEMA"; + +-- 1. CREATE TABLES TAP_SCHEMA.* + +-- WARNING: the order of columns in TAP_SCHEMA.columns has changed between tap_schema_1.0.sql and tap_schema_1.1.sql! +-- All your own ingestion SQL scripts should be adapted except if the order of columns is explicitly given in the INSERT INTO instruction. + +CREATE TABLE "TAP_SCHEMA"."schemas" ("schema_name" VARCHAR PRIMARY KEY, "description" VARCHAR , "utype" VARCHAR); +CREATE TABLE "TAP_SCHEMA"."tables" ("schema_name" VARCHAR NOT NULL , "table_name" VARCHAR PRIMARY KEY, "table_type" VARCHAR NOT NULL DEFAULT 'table' , "description" VARCHAR, "utype" VARCHAR, "table_index" INTEGER DEFAULT -1); +CREATE TABLE "TAP_SCHEMA"."columns" ("table_name" VARCHAR , "column_name" VARCHAR , "datatype" VARCHAR NOT NULL , "arraysize" INTEGER , "size" INTEGER , "description" VARCHAR, "utype" VARCHAR, "unit" VARCHAR, "ucd" VARCHAR, "indexed" SMALLINT NOT NULL DEFAULT 0 CHECK("indexed" BETWEEN 0 AND 1), "principal" SMALLINT NOT NULL DEFAULT 0 CHECK("principal" BETWEEN 0 AND 1), "std" SMALLINT NOT NULL DEFAULT 0 CHECK("std" BETWEEN 0 AND 1), "column_index" INTEGER DEFAULT -1, PRIMARY KEY("table_name","column_name")); +CREATE TABLE "TAP_SCHEMA"."keys" ("key_id" VARCHAR PRIMARY KEY , "from_table" VARCHAR NOT NULL , "target_table" VARCHAR NOT NULL, "description" VARCHAR, "utype" VARCHAR); +CREATE TABLE "TAP_SCHEMA"."key_columns" ("key_id" VARCHAR , "from_column" VARCHAR , "target_column" VARCHAR , PRIMARY KEY("key_id", "from_column", "target_column")); + +-- 2. FILL TAP_SCHEMA.schemas + +INSERT INTO "TAP_SCHEMA"."schemas" VALUES ('TAP_SCHEMA', 'Set of tables listing and describing the schemas, tables and columns published in this TAP service.', NULL); + +-- 2bis. FILL TAP_SCHEMA.tables + +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.schemas' , 'table', 'List of schemas published in this TAP service.' , NULL, 0); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.tables' , 'table', 'List of tables published in this TAP service.' , NULL, 1); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.columns' , 'table', 'List of columns of all tables listed in TAP_SCHEMA.TABLES and published in this TAP service.' , NULL, 2); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.keys' , 'table', 'List all foreign keys but provides just the tables linked by the foreign key. To know which columns of these tables are linked, see in TAP_SCHEMA.key_columns using the key_id.', NULL, 3); +INSERT INTO "TAP_SCHEMA"."tables" VALUES ('TAP_SCHEMA', 'TAP_SCHEMA.key_columns', 'table', 'List all foreign keys but provides just the columns linked by the foreign key. To know the table of these columns, see in TAP_SCHEMA.keys using the key_id.' , NULL, 4); + +-- 2ter. FILL TAP_SCHEMA.columns + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.schemas', 'schema_name', 'VARCHAR', -1, -1, 'schema name, possibly qualified' , NULL, NULL, NULL, 1, 1, 1, 0); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.schemas', 'description', 'VARCHAR', -1, -1, 'brief description of schema' , NULL, NULL, NULL, 0, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.schemas', 'utype' , 'VARCHAR', -1, -1, 'UTYPE if schema corresponds to a data model', NULL, NULL, NULL, 0, 0, 1, 2); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'table_index', 'INTEGER', -1, -1, 'this index is used to recommend table ordering for clients' , NULL, NULL, NULL, 0, 0, 1, 0); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'schema_name', 'VARCHAR', -1, -1, 'the schema name from TAP_SCHEMA.schemas' , NULL, NULL, NULL, 0, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'table_name' , 'VARCHAR', -1, -1, 'table name as it should be used in queries' , NULL, NULL, NULL, 1, 1, 1, 2); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'table_type' , 'VARCHAR', -1, -1, 'one of: table, view' , NULL, NULL, NULL, 0, 0, 1, 3); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'description', 'VARCHAR', -1, -1, 'brief description of table' , NULL, NULL, NULL, 0, 1, 1, 4); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.tables', 'utype' , 'VARCHAR', -1, -1, 'UTYPE if table corresponds to a data model' , NULL, NULL, NULL, 0, 0, 1, 5); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'column_index', 'INTEGER' , -1, -1, 'this index is used to recommend column ordering for clients' , NULL, NULL, NULL, 0, 0, 1, 0); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'table_name' , 'VARCHAR' , -1, -1, 'table name from TAP_SCHEMA.tables' , NULL, NULL, NULL, 1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'column_name' , 'VARCHAR' , -1, -1, 'column name' , NULL, NULL, NULL, 1, 1, 1, 2); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'datatype' , 'VARCHAR' , -1, -1, 'an XType or a TAPType' , NULL, NULL, NULL, 0, 1, 1, 3); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'arraysize' , 'INTEGER' , -1, -1, 'length of variable length datatypes' , NULL, NULL, NULL, 0, 0, 1, 4); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', '"size"' , 'INTEGER' , -1, -1, 'same as "arraysize" but kept for backward compatibility only', NULL, NULL, NULL, 0, 0, 1, 5); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'description' , 'VARCHAR' , -1, -1, 'brief description of column' , NULL, NULL, NULL, 0, 1, 1, 6); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'utype' , 'VARCHAR' , -1, -1, 'UTYPE of column if any' , NULL, NULL, NULL, 0, 0, 1, 7); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'unit' , 'VARCHAR' , -1, -1, 'unit in VO standard format' , NULL, NULL, NULL, 0, 1, 1, 8); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'ucd' , 'VARCHAR' , -1, -1, 'UCD of column if any' , NULL, NULL, NULL, 0, 1, 1, 9); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'indexed' , 'SMALLINT', -1, -1, 'an indexed column; 1 means true, 0 means false' , NULL, NULL, NULL, 0, 0, 1, 10); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'principal' , 'SMALLINT', -1, -1, 'a principal column; 1 means true, 0 means false' , NULL, NULL, NULL, 0, 0, 1, 11); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.columns', 'std' , 'SMALLINT', -1, -1, 'a standard column; 1 means true, 0 means false' , NULL, NULL, NULL, 0, 0, 1, 12); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'key_id' , 'VARCHAR', -1, -1, 'unique key identifier' , NULL, NULL, NULL, 1, 1, 1, 0); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'from_table' , 'VARCHAR', -1, -1, 'fully qualified table name', NULL, NULL, NULL, 0, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'target_table', 'VARCHAR', -1, -1, 'fully qualified table name', NULL, NULL, NULL, 0, 1, 1, 2); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'description' , 'VARCHAR', -1, -1, 'description of this key' , NULL, NULL, NULL, 0, 1, 1, 3); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.keys', 'utype' , 'VARCHAR', -1, -1, 'utype of this key' , NULL, NULL, NULL, 0, 0, 1, 4); + +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.key_columns', 'key_id' , 'VARCHAR', -1, -1, 'unique key identifier' , NULL, NULL, NULL, 1, 1, 1, 0); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.key_columns', 'from_column' , 'VARCHAR', -1, -1, 'key column name in the from_table' , NULL, NULL, NULL, 1, 1, 1, 1); +INSERT INTO "TAP_SCHEMA"."columns" VALUES ('TAP_SCHEMA.key_columns', 'target_column', 'VARCHAR', -1, -1, 'key column name in the target_table', NULL, NULL, NULL, 1, 1, 1, 2); + +COMMIT; diff --git a/examples/tap/tap_schema/tap_schema_adaptation_1.0_1.1.sql b/examples/tap/tap_schema/tap_schema_adaptation_1.0_1.1.sql new file mode 100644 index 0000000000000000000000000000000000000000..2ff99ed16c1ca6a5311920ab5d9c2e66b8fb00ce --- /dev/null +++ b/examples/tap/tap_schema/tap_schema_adaptation_1.0_1.1.sql @@ -0,0 +1,86 @@ +-- SQL Script based on TAP 1.1 (http://www.ivoa.net/documents/TAP/20160428/WD-TAP-1.1-20160428.pdf) +-- +-- DESCRIPTION: +-- This script adds new columns (i.e. arraysize, table_index and column_index) in the existing tables +-- of TAP_SCHEMA and adds corresponding entries in TAP_SCHEMA.columns. After execution of this script, +-- the TAP_SCHEMA should be entirely compatible with a TAP 1.1 service. +-- +-- The whole script is executed in a transaction in order to avoid partial modification of TAP_SCHEMA +-- in case of an SQL error. +-- +-- NOTE: +-- Tested and designed for PostgreSQL ; it may work with some modifications for other DBMS +-- +-- AUTHOR: Grégory Mantelet (ARI) +-- DATE : July 2016 + + +BEGIN; + +-- 1. ADD arraysize + +ALTER TABLE "TAP_SCHEMA"."columns" ADD COLUMN "arraysize" INTEGER; + +INSERT INTO "TAP_SCHEMA"."columns" ("table_name", "column_name", "datatype", "arraysize", "size", "description", "utype", "unit", "ucd", "indexed", "principal", "std") + VALUES ('TAP_SCHEMA.columns', 'arraysize', 'INTEGER' , -1, -1, 'length of variable length datatypes', NULL, NULL, NULL, 0, 0, 1); + +UPDATE "TAP_SCHEMA"."columns" SET "arraysize" = "size"; + +-- 2. DOUBLE QUOTE size + +UPDATE "TAP_SCHEMA"."columns" SET "column_name" = '"size"' WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'size'; + +-- 3. ADD column_index + +ALTER TABLE "TAP_SCHEMA"."columns" ADD COLUMN "column_index" INTEGER DEFAULT -1; + +INSERT INTO "TAP_SCHEMA"."columns" ("table_name", "column_name", "datatype", "arraysize", "size", "description", "utype", "unit", "ucd", "indexed", "principal", "std", "column_index") + VALUES ('TAP_SCHEMA.columns', 'column_index', 'INTEGER', -1, -1, 'this index is used to recommend column ordering for clients' , NULL, NULL, NULL, 0, 0, 1, 0); + +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 0 WHERE LOWER("table_name") IN ('tap_schema.schemas', 'schemas') AND LOWER("column_name") = 'schema_name'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 1 WHERE LOWER("table_name") IN ('tap_schema.schemas', 'schemas') AND LOWER("column_name") = 'description'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 2 WHERE LOWER("table_name") IN ('tap_schema.schemas', 'schemas') AND LOWER("column_name") = 'utype'; + +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 1 WHERE LOWER("table_name") IN ('tap_schema.tables', 'tables') AND LOWER("column_name") = 'schema_name'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 2 WHERE LOWER("table_name") IN ('tap_schema.tables', 'tables') AND LOWER("column_name") = 'table_name'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 3 WHERE LOWER("table_name") IN ('tap_schema.tables', 'tables') AND LOWER("column_name") = 'table_type'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 4 WHERE LOWER("table_name") IN ('tap_schema.tables', 'tables') AND LOWER("column_name") = 'description'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 5 WHERE LOWER("table_name") IN ('tap_schema.tables', 'tables') AND LOWER("column_name") = 'utype'; + +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 1 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'table_name'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 2 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'column_name'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 3 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'datatype'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 4 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'arraysize'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 5 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = '"size"'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 6 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'description'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 7 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'utype'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 8 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'unit'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 9 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'ucd'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 10 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'indexed'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 11 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'principal'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 12 WHERE LOWER("table_name") IN ('tap_schema.columns', 'columns') AND LOWER("column_name") = 'std'; + +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 0 WHERE LOWER("table_name") IN ('tap_schema.keys', 'keys') AND LOWER("column_name") = 'key_id'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 1 WHERE LOWER("table_name") IN ('tap_schema.keys', 'keys') AND LOWER("column_name") = 'from_table'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 2 WHERE LOWER("table_name") IN ('tap_schema.keys', 'keys') AND LOWER("column_name") = 'target_table'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 3 WHERE LOWER("table_name") IN ('tap_schema.keys', 'keys') AND LOWER("column_name") = 'description'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 4 WHERE LOWER("table_name") IN ('tap_schema.keys', 'keys') AND LOWER("column_name") = 'utype'; + +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 0 WHERE LOWER("table_name") IN ('tap_schema.key_columns', 'key_columns') AND LOWER("column_name") = 'key_id'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 1 WHERE LOWER("table_name") IN ('tap_schema.key_columns', 'key_columns') AND LOWER("column_name") = 'from_column'; +UPDATE "TAP_SCHEMA"."columns" SET "column_index" = 2 WHERE LOWER("table_name") IN ('tap_schema.key_columns', 'key_columns') AND LOWER("column_name") = 'target_column'; + +-- 4. ADD table_index + +ALTER TABLE "TAP_SCHEMA"."tables" ADD COLUMN "table_index" INTEGER DEFAULT -1; + +INSERT INTO "TAP_SCHEMA"."columns" ("table_name", "column_name", "datatype", "arraysize", "size", "description", "utype", "unit", "ucd", "indexed", "principal", "std", "column_index") + VALUES ('TAP_SCHEMA.tables', 'table_index', 'INTEGER', -1, -1, 'this index is used to recommend table ordering for clients', NULL, NULL, NULL, 0, 0, 1, 0); + +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-5 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('schemas', 'tap_schema.schemas'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-4 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('tables', 'tap_schema.tables'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-3 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('columns', 'tap_schema.columns'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-2 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('keys', 'tap_schema.keys'); +UPDATE "TAP_SCHEMA"."tables" SET "table_index" = (SELECT COUNT(*) FROM "TAP_SCHEMA"."tables")-1 WHERE LOWER("schema_name") = 'tap_schema' AND LOWER("table_name") IN ('key_columns', 'tap_schema.key_columns'); + +COMMIT; diff --git a/src/adql/translator/JDBCTranslator.java b/src/adql/translator/JDBCTranslator.java index a594b774a24c6eb258e01d77104eba738ead745b..053dea75b640b01afd132cfc3377c8ccbf101063 100644 --- a/src/adql/translator/JDBCTranslator.java +++ b/src/adql/translator/JDBCTranslator.java @@ -167,7 +167,7 @@ import tap.data.DataReadException; * </p> * * @author Grégory Mantelet (ARI) - * @version 1.4 (04/2016) + * @version 1.4 (07/2016) * @since 1.4 * * @see PostgreSQLTranslator @@ -329,7 +329,7 @@ public abstract class JDBCTranslator implements ADQLTranslator { * @return The string buffer + identifier. */ public StringBuffer appendIdentifier(final StringBuffer str, final String id, final boolean caseSensitive){ - if (caseSensitive) + if (caseSensitive && !id.matches("\"[^\"]*\"")) return str.append('"').append(id).append('"'); else return str.append(id); diff --git a/src/tap/db/JDBCConnection.java b/src/tap/db/JDBCConnection.java index 281718d90408a6267716d8ffe32e5da0649d14e2..be2fd3e3c96992a0cfcef1d725b96a5bc5a5e403 100644 --- a/src/tap/db/JDBCConnection.java +++ b/src/tap/db/JDBCConnection.java @@ -864,10 +864,14 @@ public class JDBCConnection implements DBConnection { /** * <p>Load into the given metadata all schemas listed in TAP_SCHEMA.schemas.</p> * - * <p><i>Note: + * <p><i>Note 1: * If schemas are not supported by this DBMS connection, the DB name of the loaded schemas is set to NULL. * </i></p> * + * <p><i>Note 2: + * Schema entries are retrieved ordered by ascending schema_name. + * </i></p> + * * @param tableDef Definition of the table TAP_SCHEMA.schemas. * @param metadata Metadata to fill with all found schemas. * @param stmt Statement to use in order to interact with the database. @@ -890,7 +894,8 @@ public class JDBCConnection implements DBConnection { sqlBuf.append(", "); translator.appendIdentifier(sqlBuf, DB_NAME_COLUMN, IdentifierField.COLUMN); } - sqlBuf.append(" FROM ").append(translator.getTableName(tableDef, supportsSchema)).append(';'); + sqlBuf.append(" FROM ").append(translator.getTableName(tableDef, supportsSchema)); + sqlBuf.append(" ORDER BY 1"); // Execute the query: rs = stmt.executeQuery(sqlBuf.toString()); @@ -921,16 +926,21 @@ public class JDBCConnection implements DBConnection { /** * <p>Load into the corresponding metadata all tables listed in TAP_SCHEMA.tables.</p> * - * <p><i>Note: + * <p><i>Note 1: * Schemas are searched in the given metadata by their ADQL name and case sensitively. * If they can not be found a {@link DBException} is thrown. * </i></p> * - * <p><i>Note: + * <p><i>Note 2: * If schemas are not supported by this DBMS connection, the DB name of the loaded * {@link TAPTable}s is prefixed by the ADQL name of their respective schema. * </i></p> * + * <p><i>Note 3: + * If the column table_index exists, table entries are retrieved ordered by ascending schema_name, then table_index, and finally table_name. + * If this column does not exist, table entries are retrieved ordered by ascending schema_name and then table_name. + * </i></p> + * * @param tableDef Definition of the table TAP_SCHEMA.tables. * @param metadata Metadata (containing already all schemas listed in TAP_SCHEMA.schemas). * @param stmt Statement to use in order to interact with the database. @@ -945,6 +955,9 @@ public class JDBCConnection implements DBConnection { // Determine whether the dbName column exists: boolean hasDBName = isColumnExisting(tableDef.getDBSchemaName(), tableDef.getDBName(), DB_NAME_COLUMN, connection.getMetaData()); + // Determine whether the tableIndex column exists: + boolean hasTableIndex = isColumnExisting(tableDef.getDBSchemaName(), tableDef.getDBName(), "table_index", connection.getMetaData()); + // Build the SQL query: StringBuffer sqlBuf = new StringBuffer("SELECT "); sqlBuf.append(translator.getColumnName(tableDef.getColumn("schema_name"))); @@ -956,7 +969,14 @@ public class JDBCConnection implements DBConnection { sqlBuf.append(", "); translator.appendIdentifier(sqlBuf, DB_NAME_COLUMN, IdentifierField.COLUMN); } - sqlBuf.append(" FROM ").append(translator.getTableName(tableDef, supportsSchema)).append(';'); + if (hasTableIndex) + sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("table_index"))); + sqlBuf.append(" FROM ").append(translator.getTableName(tableDef, supportsSchema)); + if (hasTableIndex) + sqlBuf.append(" ORDER BY 1,7,2"); + else + sqlBuf.append(" ORDER BY 1,2"); + sqlBuf.append(';'); // Execute the query: rs = stmt.executeQuery(sqlBuf.toString()); @@ -968,6 +988,7 @@ public class JDBCConnection implements DBConnection { tableName = rs.getString(2), typeStr = rs.getString(3), description = rs.getString(4), utype = rs.getString(5), dbName = (hasDBName ? rs.getString(6) : null); + int tableIndex = (hasTableIndex ? (rs.getObject(7) == null ? -1 : rs.getInt(7)) : -1); // get the schema: TAPSchema schema = metadata.getSchema(schemaName); @@ -1001,6 +1022,7 @@ public class JDBCConnection implements DBConnection { // create the new table: TAPTable newTable = new TAPTable(tableName, type, nullifyIfNeeded(description), nullifyIfNeeded(utype)); newTable.setDBName(dbName); + newTable.setIndex(tableIndex); // add the new table inside its corresponding schema: schema.addTable(newTable); @@ -1025,6 +1047,11 @@ public class JDBCConnection implements DBConnection { * If they can not be found a {@link DBException} is thrown. * </i></p> * + * <p><i>Note 2: + * If the column column_index exists, column entries are retrieved ordered by ascending table_name, then column_index, and finally column_name. + * If this column does not exist, column entries are retrieved ordered by ascending table_name and then column_name. + * </i></p> + * * @param tableDef Definition of the table TAP_SCHEMA.columns. * @param lstTables List of all published tables (= all tables listed in TAP_SCHEMA.tables). * @param stmt Statement to use in order to interact with the database. @@ -1034,9 +1061,15 @@ public class JDBCConnection implements DBConnection { protected void loadColumns(final TAPTable tableDef, final List<TAPTable> lstTables, final Statement stmt) throws DBException{ ResultSet rs = null; try{ + // Determine whether the dbName column exists: + boolean hasArraysize = isColumnExisting(tableDef.getDBSchemaName(), tableDef.getDBName(), "arraysize", connection.getMetaData()); + // Determine whether the dbName column exists: boolean hasDBName = isColumnExisting(tableDef.getDBSchemaName(), tableDef.getDBName(), DB_NAME_COLUMN, connection.getMetaData()); + // Determine whether the columnIndex column exists: + boolean hasColumnIndex = isColumnExisting(tableDef.getDBSchemaName(), tableDef.getDBName(), "column_index", connection.getMetaData()); + // Build the SQL query: StringBuffer sqlBuf = new StringBuffer("SELECT "); sqlBuf.append(translator.getColumnName(tableDef.getColumn("table_name"))); @@ -1046,7 +1079,10 @@ public class JDBCConnection implements DBConnection { sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("ucd"))); sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("utype"))); sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("datatype"))); - sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("size"))); + if (hasArraysize) + sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("arraysize"))); + else + sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("size"))); sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("principal"))); sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("indexed"))); sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("std"))); @@ -1054,7 +1090,14 @@ public class JDBCConnection implements DBConnection { sqlBuf.append(", "); translator.appendIdentifier(sqlBuf, DB_NAME_COLUMN, IdentifierField.COLUMN); } - sqlBuf.append(" FROM ").append(translator.getTableName(tableDef, supportsSchema)).append(';'); + if (hasColumnIndex) + sqlBuf.append(", ").append(translator.getColumnName(tableDef.getColumn("column_index"))); + sqlBuf.append(" FROM ").append(translator.getTableName(tableDef, supportsSchema)); + if (hasColumnIndex) + sqlBuf.append(" ORDER BY 1,13,2"); + else + sqlBuf.append(" ORDER BY 1,2"); + sqlBuf.append(';'); // Execute the query: rs = stmt.executeQuery(sqlBuf.toString()); @@ -1067,7 +1110,8 @@ public class JDBCConnection implements DBConnection { ucd = rs.getString(5), utype = rs.getString(6), datatype = rs.getString(7), dbName = (hasDBName ? rs.getString(12) : null); - int size = rs.getInt(8); + int size = rs.getInt(8), + colIndex = (hasColumnIndex ? (rs.getObject(13) == null ? -1 : rs.getInt(13)) : -1); boolean principal = toBoolean(rs.getObject(9)), indexed = toBoolean(rs.getObject(10)), std = toBoolean(rs.getObject(11)); @@ -1101,6 +1145,7 @@ public class JDBCConnection implements DBConnection { newColumn.setIndexed(indexed); newColumn.setStd(std); newColumn.setDBName(dbName); + newColumn.setIndex(colIndex); // add the new column inside its corresponding table: table.addColumn(newColumn); @@ -1117,11 +1162,16 @@ public class JDBCConnection implements DBConnection { /** * <p>Load into the corresponding tables all keys listed in TAP_SCHEMA.keys and detailed in TAP_SCHEMA.key_columns.</p> * - * <p><i>Note: + * <p><i>Note 1: * Tables and columns are searched in the given list by their ADQL name and case sensitively. * If they can not be found a {@link DBException} is thrown. * </i></p> * + * <p><i>Note 2: + * Key entries are retrieved ordered by ascending key_id, then from_table and finally target_table. + * Key_Column entries are retrieved ordered by ascending from_column and then target_column. + * </i></p> + * * @param keysDef Definition of the table TAP_SCHEMA.keys. * @param keyColumnsDef Definition of the table TAP_SCHEMA.key_columns. * @param lstTables List of all published tables (= all tables listed in TAP_SCHEMA.tables). @@ -1138,7 +1188,8 @@ public class JDBCConnection implements DBConnection { sqlBuf.append(translator.getColumnName(keyColumnsDef.getColumn("from_column"))); sqlBuf.append(", ").append(translator.getColumnName(keyColumnsDef.getColumn("target_column"))); sqlBuf.append(" FROM ").append(translator.getTableName(keyColumnsDef, supportsSchema)); - sqlBuf.append(" WHERE ").append(translator.getColumnName(keyColumnsDef.getColumn("key_id"))).append(" = ?").append(';'); + sqlBuf.append(" WHERE ").append(translator.getColumnName(keyColumnsDef.getColumn("key_id"))).append(" = ?"); + sqlBuf.append(" ORDER BY 1,2"); keyColumnsStmt = connection.prepareStatement(sqlBuf.toString()); // Build the SQL query to get the keys: @@ -1148,7 +1199,8 @@ public class JDBCConnection implements DBConnection { sqlBuf.append(", ").append(translator.getColumnName(keysDef.getColumn("target_table"))); sqlBuf.append(", ").append(translator.getColumnName(keysDef.getColumn("description"))); sqlBuf.append(", ").append(translator.getColumnName(keysDef.getColumn("utype"))); - sqlBuf.append(" FROM ").append(translator.getTableName(keysDef, supportsSchema)).append(';'); + sqlBuf.append(" FROM ").append(translator.getTableName(keysDef, supportsSchema)); + sqlBuf.append(" ORDER BY 1,2,3;"); // Execute the query: rs = stmt.executeQuery(sqlBuf.toString()); @@ -1731,8 +1783,9 @@ public class JDBCConnection implements DBConnection { sql.append(", ").append(translator.getColumnName(metaTable.getColumn("table_type"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("description"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("utype"))); + sql.append(", ").append(translator.getColumnName(metaTable.getColumn("table_index"))); sql.append(", ").append(DB_NAME_COLUMN); - sql.append(") VALUES (?, ?, ?, ?, ?, ?);"); + sql.append(") VALUES (?, ?, ?, ?, ?, ?, ?);"); // Prepare the statement: PreparedStatement stmt = null; @@ -1757,7 +1810,8 @@ public class JDBCConnection implements DBConnection { stmt.setString(3, table.getType().toString()); stmt.setString(4, table.getDescription()); stmt.setString(5, table.getUtype()); - stmt.setString(6, (table.getDBName() == null || table.getDBName().equals(table.getADQLName())) ? null : table.getDBName()); + stmt.setInt(6, table.getIndex()); + stmt.setString(7, (table.getDBName() == null || table.getDBName().equals(table.getADQLName())) ? null : table.getDBName()); executeUpdate(stmt, nbRows); } executeBatchUpdates(stmt, nbRows); @@ -1797,12 +1851,14 @@ public class JDBCConnection implements DBConnection { sql.append(", ").append(translator.getColumnName(metaTable.getColumn("ucd"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("utype"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("datatype"))); + sql.append(", ").append(translator.getColumnName(metaTable.getColumn("arraysize"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("size"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("principal"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("indexed"))); sql.append(", ").append(translator.getColumnName(metaTable.getColumn("std"))); + sql.append(", ").append(translator.getColumnName(metaTable.getColumn("column_index"))); sql.append(", ").append(DB_NAME_COLUMN); - sql.append(") VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?);"); + sql.append(") VALUES (?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?, ?);"); // Prepare the statement: PreparedStatement stmt = null; @@ -1830,10 +1886,12 @@ public class JDBCConnection implements DBConnection { stmt.setString(6, col.getUtype()); stmt.setString(7, col.getDatatype().type.toString()); stmt.setInt(8, col.getDatatype().length); - stmt.setInt(9, col.isPrincipal() ? 1 : 0); - stmt.setInt(10, col.isIndexed() ? 1 : 0); - stmt.setInt(11, col.isStd() ? 1 : 0); - stmt.setString(12, (col.getDBName() == null || col.getDBName().equals(col.getADQLName())) ? null : col.getDBName()); + stmt.setInt(9, col.getDatatype().length); + stmt.setInt(10, col.isPrincipal() ? 1 : 0); + stmt.setInt(11, col.isIndexed() ? 1 : 0); + stmt.setInt(12, col.isStd() ? 1 : 0); + stmt.setInt(13, col.getIndex()); + stmt.setString(14, (col.getDBName() == null || col.getDBName().equals(col.getADQLName())) ? null : col.getDBName()); executeUpdate(stmt, nbRows); } executeBatchUpdates(stmt, nbRows); diff --git a/src/tap/metadata/TAPColumn.java b/src/tap/metadata/TAPColumn.java index 406af805ac95ad9334bea889e8335740a2964d73..aec7097556246ab60c1a7e74d248e7284deea2a1 100644 --- a/src/tap/metadata/TAPColumn.java +++ b/src/tap/metadata/TAPColumn.java @@ -128,6 +128,11 @@ public class TAPColumn implements DBColumn { * <i>Note: Standard TAP column field ; FALSE by default.</i> */ private boolean std = false; + /** Ordering index of this column inside its table. + * <i>Note: Standard TAP column field since TAP 1.1.</i> + * @since 2.1 */ + private int index = -1; + /** Let add some information in addition of the ones of the TAP protocol. * <i>Note: This object can be anything: an {@link Integer}, a {@link String}, a {@link Map}, a {@link List}, ... * Its content is totally free and never used or checked.</i> */ @@ -743,6 +748,28 @@ public class TAPColumn implements DBColumn { this.std = std; } + /** + * Get the ordering index of this column inside its table. + * + * @return Its ordering index. + * + * @since 2.1 + */ + public final int getIndex(){ + return index; + } + + /** + * Set the ordering index of this column inside its table. + * + * @param columnIndex Its new ordering index. + * + * @since 2.1 + */ + public final void setIndex(int columnIndex){ + this.index = columnIndex; + } + /** * <p>Get the other (piece of) information associated with this column.</p> * diff --git a/src/tap/metadata/TAPMetadata.java b/src/tap/metadata/TAPMetadata.java index d0d10f91697fc17319c63cd11ab21bc0096fec68..9684805dc277d4f300b8e9a3d8c0f02cb038e2ff 100644 --- a/src/tap/metadata/TAPMetadata.java +++ b/src/tap/metadata/TAPMetadata.java @@ -791,48 +791,51 @@ public class TAPMetadata implements Iterable<TAPSchema>, VOSIResource, TAPResour case SCHEMAS: TAPTable schemas = new TAPTable(STDSchema.TAPSCHEMA + "." + STDTable.SCHEMAS, TableType.table, "List of schemas published in this TAP service.", null); schemas.addColumn("schema_name", new DBType(DBDatatype.VARCHAR), "schema name, possibly qualified", null, null, null, true, true, true); - schemas.addColumn("description", new DBType(DBDatatype.VARCHAR), "brief description of schema", null, null, null, false, false, true); + schemas.addColumn("description", new DBType(DBDatatype.VARCHAR), "brief description of schema", null, null, null, true, false, true); schemas.addColumn("utype", new DBType(DBDatatype.VARCHAR), "UTYPE if schema corresponds to a data model", null, null, null, false, false, true); return schemas; case TABLES: TAPTable tables = new TAPTable(STDSchema.TAPSCHEMA + "." + STDTable.TABLES, TableType.table, "List of tables published in this TAP service.", null); - tables.addColumn("schema_name", new DBType(DBDatatype.VARCHAR), "the schema name from TAP_SCHEMA.schemas", null, null, null, true, true, true); + tables.addColumn("table_index", new DBType(DBDatatype.INTEGER), "this index is used to recommend table ordering for clients", null, null, null, false, false, true); + tables.addColumn("schema_name", new DBType(DBDatatype.VARCHAR), "the schema name from TAP_SCHEMA.schemas", null, null, null, true, false, true); tables.addColumn("table_name", new DBType(DBDatatype.VARCHAR), "table name as it should be used in queries", null, null, null, true, true, true); tables.addColumn("table_type", new DBType(DBDatatype.VARCHAR), "one of: table, view", null, null, null, false, false, true); - tables.addColumn("description", new DBType(DBDatatype.VARCHAR), "brief description of table", null, null, null, false, false, true); + tables.addColumn("description", new DBType(DBDatatype.VARCHAR), "brief description of table", null, null, null, true, false, true); tables.addColumn("utype", new DBType(DBDatatype.VARCHAR), "UTYPE if table corresponds to a data model", null, null, null, false, false, true); return tables; case COLUMNS: TAPTable columns = new TAPTable(STDSchema.TAPSCHEMA + "." + STDTable.COLUMNS, TableType.table, "List of columns of all tables listed in TAP_SCHEMA.TABLES and published in this TAP service.", null); + columns.addColumn("column_index", new DBType(DBDatatype.INTEGER), "this index is used to recommend column ordering for clients", null, null, null, false, false, true); columns.addColumn("table_name", new DBType(DBDatatype.VARCHAR), "table name from TAP_SCHEMA.tables", null, null, null, true, true, true); columns.addColumn("column_name", new DBType(DBDatatype.VARCHAR), "column name", null, null, null, true, true, true); - columns.addColumn("description", new DBType(DBDatatype.VARCHAR), "brief description of column", null, null, null, false, false, true); - columns.addColumn("unit", new DBType(DBDatatype.VARCHAR), "unit in VO standard format", null, null, null, false, false, true); - columns.addColumn("ucd", new DBType(DBDatatype.VARCHAR), "UCD of column if any", null, null, null, false, false, true); + columns.addColumn("datatype", new DBType(DBDatatype.VARCHAR), "an XType or a TAPType", null, null, null, true, false, true); + columns.addColumn("arraysize", new DBType(DBDatatype.INTEGER), "length of variable length datatypes", null, null, null, false, false, true); + columns.addColumn("\"size\"", new DBType(DBDatatype.INTEGER), "same as \"arraysize\" but kept for backward compatibility only", null, null, null, false, false, true); + columns.addColumn("description", new DBType(DBDatatype.VARCHAR), "brief description of column", null, null, null, true, false, true); columns.addColumn("utype", new DBType(DBDatatype.VARCHAR), "UTYPE of column if any", null, null, null, false, false, true); - columns.addColumn("datatype", new DBType(DBDatatype.VARCHAR), "ADQL datatype as in section 2.5", null, null, null, false, false, true); - columns.addColumn("size", new DBType(DBDatatype.INTEGER), "length of variable length datatypes", null, null, null, false, false, true); - columns.addColumn("principal", new DBType(DBDatatype.INTEGER), "a principal column; 1 means true, 0 means false", null, null, null, false, false, true); + columns.addColumn("unit", new DBType(DBDatatype.VARCHAR), "unit in VO standard format", null, null, null, true, false, true); + columns.addColumn("ucd", new DBType(DBDatatype.VARCHAR), "UCD of column if any", null, null, null, true, false, true); columns.addColumn("indexed", new DBType(DBDatatype.INTEGER), "an indexed column; 1 means true, 0 means false", null, null, null, false, false, true); + columns.addColumn("principal", new DBType(DBDatatype.INTEGER), "a principal column; 1 means true, 0 means false", null, null, null, false, false, true); columns.addColumn("std", new DBType(DBDatatype.INTEGER), "a standard column; 1 means true, 0 means false", null, null, null, false, false, true); return columns; case KEYS: TAPTable keys = new TAPTable(STDSchema.TAPSCHEMA + "." + STDTable.KEYS, TableType.table, "List all foreign keys but provides just the tables linked by the foreign key. To know which columns of these tables are linked, see in TAP_SCHEMA.key_columns using the key_id.", null); keys.addColumn("key_id", new DBType(DBDatatype.VARCHAR), "unique key identifier", null, null, null, true, true, true); - keys.addColumn("from_table", new DBType(DBDatatype.VARCHAR), "fully qualified table name", null, null, null, false, false, true); - keys.addColumn("target_table", new DBType(DBDatatype.VARCHAR), "fully qualified table name", null, null, null, false, false, true); - keys.addColumn("description", new DBType(DBDatatype.VARCHAR), "description of this key", null, null, null, false, false, true); + keys.addColumn("from_table", new DBType(DBDatatype.VARCHAR), "fully qualified table name", null, null, null, true, false, true); + keys.addColumn("target_table", new DBType(DBDatatype.VARCHAR), "fully qualified table name", null, null, null, true, false, true); + keys.addColumn("description", new DBType(DBDatatype.VARCHAR), "description of this key", null, null, null, true, false, true); keys.addColumn("utype", new DBType(DBDatatype.VARCHAR), "utype of this key", null, null, null, false, false, true); return keys; case KEY_COLUMNS: TAPTable key_columns = new TAPTable(STDSchema.TAPSCHEMA + "." + STDTable.KEY_COLUMNS, TableType.table, "List all foreign keys but provides just the columns linked by the foreign key. To know the table of these columns, see in TAP_SCHEMA.keys using the key_id.", null); key_columns.addColumn("key_id", new DBType(DBDatatype.VARCHAR), "unique key identifier", null, null, null, true, true, true); - key_columns.addColumn("from_column", new DBType(DBDatatype.VARCHAR), "key column name in the from_table", null, null, null, false, false, true); - key_columns.addColumn("target_column", new DBType(DBDatatype.VARCHAR), "key column name in the target_table", null, null, null, false, false, true); + key_columns.addColumn("from_column", new DBType(DBDatatype.VARCHAR), "key column name in the from_table", null, null, null, true, true, true); + key_columns.addColumn("target_column", new DBType(DBDatatype.VARCHAR), "key column name in the target_table", null, null, null, true, true, true); return key_columns; default: diff --git a/src/tap/metadata/TAPTable.java b/src/tap/metadata/TAPTable.java index 905394cdf1c3f7fce2fb92c750cb5f77b220249b..c89df9ce892083b8003b7f46cbcaa4b97d6d0727 100644 --- a/src/tap/metadata/TAPTable.java +++ b/src/tap/metadata/TAPTable.java @@ -111,6 +111,11 @@ public class TAPTable implements DBTable { * <i>Note: Standard TAP table field ; MAY be NULL.</i> */ private String utype = null; + /** Ordering index of this table inside its schema. + * <i>Note: Standard TAP table field since TAP 1.1.</i> + * @since 2.1 */ + private int index = -1; + /** List of columns composing this table. * <i>Note: all columns of this list are linked to this table from the moment they are added inside it.</i> */ protected final Map<String,TAPColumn> columns; @@ -509,6 +514,28 @@ public class TAPTable implements DBTable { this.utype = utype; } + /** + * Get the ordering index of this table inside its schema. + * + * @return Its ordering index. + * + * @since 2.1 + */ + public final int getIndex(){ + return index; + } + + /** + * Set the ordering index of this table inside its schema. + * + * @param tableIndex Its new ordering index. + * + * @since 2.1 + */ + public final void setIndex(int tableIndex){ + this.index = tableIndex; + } + /** * <p>Get the other (piece of) information associated with this table.</p> * diff --git a/src/tap/metadata/TableSetParser.java b/src/tap/metadata/TableSetParser.java index 0d6e1a5fdc49b5fee46c38233dabe5cd1ea7abba..a7e2d27787d7ac9bb00377dfddd76a52648cdcf3 100644 --- a/src/tap/metadata/TableSetParser.java +++ b/src/tap/metadata/TableSetParser.java @@ -16,7 +16,7 @@ package tap.metadata; * You should have received a copy of the GNU Lesser General Public License * along with TAPLibrary. If not, see <http://www.gnu.org/licenses/>. * - * Copyright 2015 - Astronomisches Rechen Institut (ARI) + * Copyright 2015-2016 - Astronomisches Rechen Institut (ARI) */ import java.io.BufferedInputStream; @@ -37,11 +37,11 @@ import javax.xml.stream.XMLStreamReader; import org.xml.sax.helpers.DefaultHandler; +import adql.db.DBType; +import adql.db.DBType.DBDatatype; import tap.TAPException; import tap.data.VOTableIterator; import tap.metadata.TAPTable.TableType; -import adql.db.DBType; -import adql.db.DBType.DBDatatype; /** * <p>Let parse an XML document representing a table set, and return the corresponding {@link TAPMetadata} instance.</p> @@ -78,7 +78,7 @@ import adql.db.DBType.DBDatatype; * </ul> * * @author Grégory Mantelet (ARI) - * @version 2.0 (02/2015) + * @version 2.1 (07/2016) * @since 2.0 */ public class TableSetParser extends DefaultHandler { @@ -95,7 +95,7 @@ public class TableSetParser extends DefaultHandler { * <p> * An instance of this class lets save all information provided in the XML document and needed to create the corresponding TAP metadata ({@link TAPForeignKey}) * at the end of XML document parsing, once all available tables are listed. - * </p> + * </p> * * @author Grégory Mantelet (ARI) * @version 2.0 (02/2015) @@ -257,7 +257,8 @@ public class TableSetParser extends DefaultHandler { throw new IllegalStateException(getPosition(reader) + " Illegal usage of TableSetParser.parseSchema(XMLStreamParser)! This function can be called only when the reader has just read the START ELEMENT tag \"schema\"."); TAPSchema schema = null; - String tag = null, name = null, description = null, title = null, utype = null; + String tag = null, name = null, description = null, title = null, + utype = null; ArrayList<TAPTable> tables = new ArrayList<TAPTable>(10); while(nextTag(reader) == XMLStreamConstants.START_ELEMENT){ @@ -273,7 +274,9 @@ public class TableSetParser extends DefaultHandler { description = ((description != null) ? (description + "\n") : "") + getText(reader); else if (tag.equalsIgnoreCase("table")){ ArrayList<ForeignKey> keys = new ArrayList<ForeignKey>(2); - tables.add(parseTable(reader, keys)); + TAPTable newTable = parseTable(reader, keys); + newTable.setIndex(tables.size()); + tables.add(newTable); allForeignKeys.addAll(keys); }else if (tag.equalsIgnoreCase("title")) title = ((title != null) ? (title + "\n") : "") + getText(reader); @@ -342,7 +345,8 @@ public class TableSetParser extends DefaultHandler { TAPTable table = null; TableType type = TableType.table; - String tag = null, name = null, description = null, title = null, utype = null; + String tag = null, name = null, description = null, title = null, + utype = null; ArrayList<TAPColumn> columns = new ArrayList<TAPColumn>(10); // Get the table type (attribute "type") [OPTIONAL] : @@ -379,7 +383,9 @@ public class TableSetParser extends DefaultHandler { }else if (tag.equalsIgnoreCase("description")) description = ((description != null) ? (description + "\n") : "") + getText(reader); else if (tag.equalsIgnoreCase("column")){ - columns.add(parseColumn(reader)); + TAPColumn newCol = parseColumn(reader); + newCol.setIndex(columns.size()); + columns.add(newCol); }else if (tag.equalsIgnoreCase("foreignKey")) keys.add(parseFKey(reader)); else if (tag.equalsIgnoreCase("title")) @@ -446,7 +452,8 @@ public class TableSetParser extends DefaultHandler { TAPColumn column = null; boolean std = false, indexed = false, primary = false, nullable = false; - String tag = null, name = null, description = null, unit = null, ucd = null, utype = null; + String tag = null, name = null, description = null, unit = null, + ucd = null, utype = null; DBType type = null; // Get the column STD flag (attribute "std") [OPTIONAL] : @@ -550,7 +557,8 @@ public class TableSetParser extends DefaultHandler { if (reader.getEventType() != XMLStreamConstants.START_ELEMENT || reader.getLocalName() == null || !reader.getLocalName().equalsIgnoreCase("dataType")) throw new IllegalStateException(getPosition(reader) + " Illegal usage of TableSetParser.parseDataType(XMLStreamParser)! This function can be called only when the reader has just read the START ELEMENT tag \"dataType\"."); - String typeOfType = null, datatype = null, size = null, xtype = null, arraysize = null; + String typeOfType = null, datatype = null, size = null, xtype = null, + arraysize = null; /* Note: * The 1st parameter of XMLStreamReader.getAttributeValue(String, String) should be the namespace of the attribute. @@ -776,7 +784,7 @@ public class TableSetParser extends DefaultHandler { * @throws XMLStreamException If there is an error processing the underlying XML source. * @throws TAPException If the name of the only corresponding end element does not match the given one, * or if the END ELEMENT can not be found <i>(2 possible reasons for that: - * 1/ malformed XML document, 2/ this function has been called before the START ELEMENT has been read)</i>. + * 1/ malformed XML document, 2/ this function has been called before the START ELEMENT has been read)</i>. */ protected final void goToEndTag(final XMLStreamReader reader, final String startNode) throws XMLStreamException, TAPException{ if (startNode == null || startNode.trim().length() <= 0) @@ -860,7 +868,7 @@ public class TableSetParser extends DefaultHandler { if (tableName.indexOf('.') >= 0){ // get the schema name: schema = tableName.substring(0, tableName.indexOf('.')).trim(); - // test that the schema name is not null: + // test that the schema name is not null: if (schema.length() == 0) throw new TAPException(position + " Incorrect full table name - \"" + tableName + "\": empty schema name!"); // test that the remaining table name is not null: