Skip to content
Merged
Show file tree
Hide file tree
Changes from all commits
Commits
File filter

Filter by extension

Filter by extension

Conversations
Failed to load comments.
Loading
Jump to
Jump to file
Failed to load files.
Loading
Diff view
Diff view
48 changes: 48 additions & 0 deletions postgres/drafts/02_add_datasets.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,48 @@
BEGIN;

--------------------------------------
-- ICRS: datasets is pretty simple
-- Probably, it is necessary to add a field "spectral range" (optical, X-ray, radio, etc.)
--------------------------------------

CREATE TABLE icrs.datasets (
id Integer PRIMARY KEY
, table_id Integer NOT NULL REFERENCES layer0.tables (id) ON DELETE restrict ON UPDATE cascade
, column_name Text NOT NULL
, datatype Common.DataType NOT NULL
) ;

ALTER TABLE icrs.data
ADD COLUMN dataset_id Integer NOT NULL REFERENCES icrs.datasets(id) ON DELETE restrict ON UPDATE cascade,
DROP COLUMN modification_time ;

CREATE VIEW icrs.dataview AS
SELECT
r.pgc
, d.ra
, d.e_ra
, d.dec
, d.e_dec
, s.datatype

, d.record_id
, d.dataset_id
, s.table_id
, t.table_name
, s.column_name

, b.code
, b.year
, b.author
, b.title

, r.modification_time
FROM
icrs.data AS d
LEFT JOIN icrs.datasets AS s ON (d.dataset_id = s.id )
LEFT JOIN layer0.records AS r ON (d.record_id = r.id )
LEFT JOIN layer0.tables AS t ON (d.table_id = t.id )
LEFT JOIN common.bib AS b ON (t.bib = b.id )
;

COMMIT;
67 changes: 67 additions & 0 deletions postgres/migrations/V013_pgc.sql
Original file line number Diff line number Diff line change
@@ -0,0 +1,67 @@
BEGIN;

-- ALTER ROLE dim WITH SUPERUSER ;

-------------------------------------------------------------
-- Сохранять время модификации PGC нет необходимости,
-- т.к. есть время привязки объекта с записями и этого достаточно для отслеживания модификаций
--
-- добавление нового PGC номера делается командой
-- INSERT INTO common.pgc DEFAULT VALUES ;
-------------------------------------------------------------

CREATE TABLE common.pgc (
id Serial PRIMARY KEY
);

COMMENT ON TABLE common.pgc IS 'The list of existing PGC-numbers' ;
COMMENT ON COLUMN common.pgc.id IS 'Unique PGC-number' ;


--------------------------
-- Ассоциация записей с PGC номерами переносится в таблицу objects
--------------------------

ALTER TABLE rawdata.objects
ADD COLUMN pgc Integer REFERENCES common.pgc (id) ON DELETE restrict ON UPDATE cascade,
ADD COLUMN modification_time Timestamp Without Time Zone ;

COMMENT ON TABLE rawdata.objects IS 'The register of all objects in original data tables' ;
COMMENT ON COLUMN rawdata.objects.id IS 'The record id' ;
COMMENT ON COLUMN rawdata.objects.table_id IS 'The table in which the record is located' ;
COMMENT ON COLUMN rawdata.objects.pgc IS 'Corssidentification of the record with the PGC-number' ;
COMMENT ON COLUMN rawdata.objects.modification_time IS 'Time of PGC-number assignment to the record' ;


---------------------------
-- Перенос данных
---------------------------

INSERT INTO common.pgc (id)
SELECT id
FROM rawdata.pgc
ORDER BY rawdata.pgc.id
;

ALTER SEQUENCE common.pgc_id_seq RESTART WITH 6775395 ;

UPDATE rawdata.objects
SET
pgc=rawdata.pgc.id
FROM rawdata.pgc
WHERE
rawdata.pgc.object_id=rawdata.objects.id
;


--------------------------------------
-- В дальнейшем нужно будет
-- 1. Перенести связь между записями и PGC в таблицу objects
-- 2. Удалить таблицу rawdata.pgc
-- 3. Перименовать таблицу objects в records
-- 4. Перенести таблицы records и tables в схему layer0
--------------------------------------

-- ROLLBACK;
COMMIT;

Loading