-
-
Notifications
You must be signed in to change notification settings - Fork 138
/
Copy path00-init.sql
140 lines (112 loc) · 3.49 KB
/
00-init.sql
1
2
3
4
5
6
7
8
9
10
11
12
13
14
15
16
17
18
19
20
21
22
23
24
25
26
27
28
29
30
31
32
33
34
35
36
37
38
39
40
41
42
43
44
45
46
47
48
49
50
51
52
53
54
55
56
57
58
59
60
61
62
63
64
65
66
67
68
69
70
71
72
73
74
75
76
77
78
79
80
81
82
83
84
85
86
87
88
89
90
91
92
93
94
95
96
97
98
99
100
101
102
103
104
105
106
107
108
109
110
111
112
113
114
115
116
117
118
119
120
121
122
123
124
125
126
127
128
129
130
131
132
133
134
135
136
137
138
139
140
-- Tables for testing
CREATE TYPE public.user_status AS ENUM ('ACTIVE', 'INACTIVE');
CREATE TYPE composite_type_with_array_attribute AS (my_text_array text[]);
CREATE TABLE public.users (
id bigint GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
name text,
status user_status DEFAULT 'ACTIVE'
);
INSERT INTO
public.users (name)
VALUES
('Joe Bloggs'),
('Jane Doe');
CREATE TABLE public.todos (
id bigint GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
details text,
"user-id" bigint REFERENCES users NOT NULL
);
INSERT INTO
public.todos (details, "user-id")
VALUES
('Star the repo', 1),
('Watch the releases', 2);
CREATE FUNCTION add(integer, integer) RETURNS integer
AS 'select $1 + $2;'
LANGUAGE SQL
IMMUTABLE
RETURNS NULL ON NULL INPUT;
create table public.users_audit (
id BIGINT generated by DEFAULT as identity,
created_at timestamptz DEFAULT now(),
user_id bigint,
previous_value jsonb
);
create function public.audit_action()
returns trigger as $$
begin
insert into public.users_audit (user_id, previous_value)
values (old.id, row_to_json(old));
return new;
end;
$$ language plpgsql;
CREATE VIEW todos_view AS SELECT * FROM public.todos;
-- For testing typegen on view-to-view relationships
create view users_view as select * from public.users;
create materialized view todos_matview as select * from public.todos;
create function public.blurb(public.todos) returns text as
$$
select substring($1.details, 1, 3);
$$ language sql stable;
create function public.blurb_varchar(public.todos) returns character varying as
$$
select substring($1.details, 1, 3);
$$ language sql stable;
create function public.details_length(public.todos) returns integer as
$$
select length($1.details);
$$ language sql stable;
create function public.details_is_long(public.todos) returns boolean as
$$
select $1.details_length > 20;
$$ language sql stable;
create function public.details_words(public.todos) returns text[] as
$$
select string_to_array($1.details, ' ');
$$ language sql stable;
create extension pg_jsonschema;
create extension postgres_fdw;
create server foreign_server foreign data wrapper postgres_fdw options (host 'localhost', port '5432', dbname 'postgres');
create user mapping for postgres server foreign_server options (user 'postgres', password 'postgres');
create foreign table foreign_table (
id int8 not null,
name text,
status user_status
) server foreign_server options (schema_name 'public', table_name 'users');
create or replace function public.function_returning_row()
returns public.users
language sql
stable
as $$
select * from public.users limit 1;
$$;
create or replace function public.function_returning_set_of_rows()
returns setof public.users
language sql
stable
as $$
select * from public.users;
$$;
create or replace function public.function_returning_table()
returns table (id int, name text)
language sql
stable
as $$
select id, name from public.users;
$$;
create or replace function public.polymorphic_function(text) returns void language sql as '';
create or replace function public.polymorphic_function(bool) returns void language sql as '';
create table user_details (
user_id int8 references users(id) primary key,
details text
);
create view a_view as select id from users;
create table empty();
create table table_with_other_tables_row_type (
col1 user_details,
col2 a_view
);
create table table_with_primary_key_other_than_id (
other_id bigint GENERATED BY DEFAULT AS IDENTITY PRIMARY KEY,
name text
);