|
1
|
|
|
<?php |
|
2
|
|
|
|
|
3
|
|
|
namespace Lagdo\DbAdmin\Driver\PgSql\Db; |
|
4
|
|
|
|
|
5
|
|
|
use Lagdo\DbAdmin\Driver\Entity\TableFieldEntity; |
|
6
|
|
|
use Lagdo\DbAdmin\Driver\Entity\TableEntity; |
|
7
|
|
|
use Lagdo\DbAdmin\Driver\Entity\IndexEntity; |
|
8
|
|
|
use Lagdo\DbAdmin\Driver\Entity\ForeignKeyEntity; |
|
9
|
|
|
|
|
10
|
|
|
trait TableTrait |
|
11
|
|
|
{ |
|
12
|
|
|
/** |
|
13
|
|
|
* @param string $table |
|
14
|
|
|
* |
|
15
|
|
|
* @return array |
|
16
|
|
|
*/ |
|
17
|
|
|
private function queryStatus(string $table = '') |
|
18
|
|
|
{ |
|
19
|
|
|
$query = "SELECT c.relname AS \"Name\", CASE c.relkind " . |
|
20
|
|
|
"WHEN 'r' THEN 'table' WHEN 'm' THEN 'materialized view' ELSE 'view' END AS \"Engine\", " . |
|
21
|
|
|
"pg_relation_size(c.oid) AS \"Data_length\", " . |
|
22
|
|
|
"pg_total_relation_size(c.oid) - pg_relation_size(c.oid) AS \"Index_length\", " . |
|
23
|
|
|
"obj_description(c.oid, 'pg_class') AS \"Comment\", " . |
|
24
|
|
|
($this->driver->minVersion(12) ? "''" : "CASE WHEN c.relhasoids THEN 'oid' ELSE '' END") . |
|
25
|
|
|
" AS \"Oid\", c.reltuples as \"Rows\", n.nspname FROM pg_class c " . |
|
26
|
|
|
"JOIN pg_namespace n ON(n.nspname = current_schema() AND n.oid = c.relnamespace) " . |
|
27
|
|
|
"WHERE relkind IN ('r', 'm', 'v', 'f', 'p') " . |
|
28
|
|
|
($table != "" ? "AND relname = " . $this->driver->quote($table) : "ORDER BY relname"); |
|
29
|
|
|
return $this->driver->rows($query); |
|
30
|
|
|
} |
|
31
|
|
|
|
|
32
|
|
|
/** |
|
33
|
|
|
* @param array $row |
|
34
|
|
|
* |
|
35
|
|
|
* @return TableEntity |
|
36
|
|
|
*/ |
|
37
|
|
|
private function makeStatus(array $row) |
|
38
|
|
|
{ |
|
39
|
|
|
$status = new TableEntity($row['Name']); |
|
40
|
|
|
$status->engine = $row['Engine']; |
|
41
|
|
|
$status->schema = $row['nspname']; |
|
42
|
|
|
$status->dataLength = $row['Data_length']; |
|
43
|
|
|
$status->indexLength = $row['Index_length']; |
|
44
|
|
|
$status->oid = $row['Oid']; |
|
45
|
|
|
$status->rows = $row['Rows']; |
|
46
|
|
|
$status->comment = $row['Comment']; |
|
47
|
|
|
|
|
48
|
|
|
return $status; |
|
49
|
|
|
} |
|
50
|
|
|
|
|
51
|
|
|
/** |
|
52
|
|
|
* Get the primary key of a table |
|
53
|
|
|
* Same as indexes(), but the columns of the primary key are returned in a array |
|
54
|
|
|
* |
|
55
|
|
|
* @param string $table |
|
56
|
|
|
* |
|
57
|
|
|
* @return array |
|
58
|
|
|
*/ |
|
59
|
|
|
private function primaryKeyColumns(string $table) |
|
60
|
|
|
{ |
|
61
|
|
|
$indexes = []; |
|
62
|
|
|
$table_oid = $this->driver->result("SELECT oid FROM pg_class WHERE " . |
|
63
|
|
|
"relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = current_schema()) " . |
|
64
|
|
|
"AND relname = " . $this->driver->quote($table)); |
|
65
|
|
|
$columns = $this->driver->keyValues("SELECT attnum, attname FROM pg_attribute WHERE " . |
|
66
|
|
|
"attrelid = $table_oid AND attnum > 0"); |
|
67
|
|
|
foreach ($this->driver->rows("SELECT relname, indisunique::int, indisprimary::int, indkey, " . |
|
68
|
|
|
"indoption, (indpred IS NOT NULL)::int as indispartial FROM pg_index i, pg_class ci " . |
|
69
|
|
|
"WHERE i.indrelid = $table_oid AND ci.oid = i.indexrelid") as $row) |
|
70
|
|
|
{ |
|
71
|
|
|
// $relname = $row["relname"]; |
|
72
|
|
|
if ($row["indisprimary"]) { |
|
73
|
|
|
foreach (explode(" ", $row["indkey"]) as $indkey) { |
|
74
|
|
|
$indexes[] = $columns[$indkey]; |
|
75
|
|
|
} |
|
76
|
|
|
} |
|
77
|
|
|
} |
|
78
|
|
|
return $indexes; |
|
79
|
|
|
} |
|
80
|
|
|
|
|
81
|
|
|
/** |
|
82
|
|
|
* @param array $row |
|
83
|
|
|
* |
|
84
|
|
|
* @return string |
|
85
|
|
|
*/ |
|
86
|
|
|
private function getFieldDefault(array $row) |
|
87
|
|
|
{ |
|
88
|
|
|
$values = [ |
|
89
|
|
|
'a' => 'GENERATED ALWAYS AS IDENTITY', |
|
90
|
|
|
'd' => 'GENERATED BY DEFAULT AS IDENTITY', |
|
91
|
|
|
]; |
|
92
|
|
|
$default = isset($values[$row['identity']]) ? $values[$row['identity']] : $row["default"]; |
|
93
|
|
|
if (!preg_match('~(.+)::[^,)]+(.*)~', $row["default"] ?? '', $match)) { |
|
94
|
|
|
return $default; |
|
95
|
|
|
} |
|
96
|
|
|
$match = array_pad($match, 3, ''); |
|
97
|
|
|
if ($match[1] == "NULL") { |
|
98
|
|
|
return null; |
|
99
|
|
|
} |
|
100
|
|
|
if (!empty($match[1]) && $match[1][0] == "'") { |
|
101
|
|
|
return $this->driver->unescapeId($match[1]) . $match[2]; |
|
102
|
|
|
} |
|
103
|
|
|
return $match[1] . $match[2]; |
|
104
|
|
|
} |
|
105
|
|
|
|
|
106
|
|
|
/** |
|
107
|
|
|
* @param array $row |
|
108
|
|
|
* |
|
109
|
|
|
* @return array |
|
110
|
|
|
*/ |
|
111
|
|
|
private function getFieldTypes(array $row) |
|
112
|
|
|
{ |
|
113
|
|
|
$aliases = [ |
|
114
|
|
|
'timestamp without time zone' => 'timestamp', |
|
115
|
|
|
'timestamp with time zone' => 'timestamptz', |
|
116
|
|
|
]; |
|
117
|
|
|
preg_match('~([^([]+)(\((.*)\))?([a-z ]+)?((\[[0-9]*])*)$~', $row["full_type"], $match); |
|
118
|
|
|
list(, $type, $_length, $length, $addon, $array) = $match; |
|
119
|
|
|
$length .= $array; |
|
120
|
|
|
$checkType = $type . $addon; |
|
121
|
|
|
if (isset($aliases[$checkType])) { |
|
122
|
|
|
$type = $aliases[$checkType]; |
|
123
|
|
|
$fullType = $type . $_length . $array; |
|
124
|
|
|
return [$length, $type, $fullType]; |
|
125
|
|
|
} |
|
126
|
|
|
$fullType = $type . $_length . $addon . $array; |
|
127
|
|
|
return [$length, $type, $fullType]; |
|
128
|
|
|
} |
|
129
|
|
|
|
|
130
|
|
|
/** |
|
131
|
|
|
* @param array $row |
|
132
|
|
|
* @param array $primaryKeyColumns |
|
133
|
|
|
* |
|
134
|
|
|
* @return TableFieldEntity |
|
135
|
|
|
*/ |
|
136
|
|
|
private function makeFieldEntity(array $row, array $primaryKeyColumns) |
|
137
|
|
|
{ |
|
138
|
|
|
$field = new TableFieldEntity(); |
|
139
|
|
|
|
|
140
|
|
|
$field->name = $row["field"]; |
|
141
|
|
|
$field->primary = \in_array($field->name, $primaryKeyColumns); |
|
142
|
|
|
$field->fullType = $row["full_type"]; |
|
143
|
|
|
$field->default = $this->getFieldDefault($row); |
|
144
|
|
|
$field->comment = $row["comment"]; |
|
145
|
|
|
//! No collation, no info about primary keys |
|
146
|
|
|
list($field->length, $field->type, $field->fullType) = $this->getFieldTypes($row); |
|
147
|
|
|
$field->null = !$row["attnotnull"]; |
|
148
|
|
|
$field->autoIncrement = $row['identity'] || preg_match('~^nextval\(~i', $row["default"] ?? ''); |
|
149
|
|
|
$field->privileges = ["insert" => 1, "select" => 1, "update" => 1]; |
|
150
|
|
|
return $field; |
|
151
|
|
|
} |
|
152
|
|
|
|
|
153
|
|
|
/** |
|
154
|
|
|
* @param array $row |
|
155
|
|
|
* |
|
156
|
|
|
* @return string |
|
157
|
|
|
*/ |
|
158
|
|
|
private function getIndexType(array $row) |
|
159
|
|
|
{ |
|
160
|
|
|
if ($row['indispartial']) { |
|
161
|
|
|
return 'INDEX'; |
|
162
|
|
|
} |
|
163
|
|
|
if ($row['indisprimary']) { |
|
164
|
|
|
return 'PRIMARY'; |
|
165
|
|
|
} |
|
166
|
|
|
if ($row['indisunique']) { |
|
167
|
|
|
return 'UNIQUE'; |
|
168
|
|
|
} |
|
169
|
|
|
return 'INDEX'; |
|
170
|
|
|
} |
|
171
|
|
|
|
|
172
|
|
|
/** |
|
173
|
|
|
* @param array $row |
|
174
|
|
|
* @param array $columns |
|
175
|
|
|
* |
|
176
|
|
|
* @return IndexEntity |
|
177
|
|
|
*/ |
|
178
|
|
|
private function makeIndexEntity(array $row, array $columns) |
|
179
|
|
|
{ |
|
180
|
|
|
$index = new IndexEntity(); |
|
181
|
|
|
|
|
182
|
|
|
$index->type = $this->getIndexType($row); |
|
183
|
|
|
$index->columns = []; |
|
184
|
|
|
foreach (explode(' ', $row['indkey']) as $indkey) { |
|
185
|
|
|
$index->columns[] = $columns[$indkey]; |
|
186
|
|
|
} |
|
187
|
|
|
$index->descs = []; |
|
188
|
|
|
foreach (explode(' ', $row['indoption']) as $indoption) { |
|
189
|
|
|
$index->descs[] = ($indoption & 1 ? '1' : null); // 1 - INDOPTION_DESC |
|
|
|
|
|
|
190
|
|
|
} |
|
191
|
|
|
$index->lengths = []; |
|
192
|
|
|
|
|
193
|
|
|
return $index; |
|
194
|
|
|
} |
|
195
|
|
|
|
|
196
|
|
|
/** |
|
197
|
|
|
* @param array $row |
|
198
|
|
|
* |
|
199
|
|
|
* @return ForeignKeyEntity |
|
200
|
|
|
*/ |
|
201
|
|
|
private function makeForeignKeyEntity(array $row) |
|
202
|
|
|
{ |
|
203
|
|
|
if (!preg_match('~FOREIGN KEY\s*\((.+)\)\s*REFERENCES (.+)\((.+)\)(.*)$~iA', $row['definition'], $match)) { |
|
204
|
|
|
return null; |
|
205
|
|
|
} |
|
206
|
|
|
$onActions = $this->driver->actions(); |
|
207
|
|
|
$match = array_pad($match, 5, ''); |
|
208
|
|
|
|
|
209
|
|
|
$foreignKey = new ForeignKeyEntity(); |
|
210
|
|
|
|
|
211
|
|
|
$foreignKey->source = array_map('trim', explode(',', $match[1])); |
|
212
|
|
|
$foreignKey->target = array_map('trim', explode(',', $match[3])); |
|
213
|
|
|
|
|
214
|
|
|
if (preg_match('~^(("([^"]|"")+"|[^"]+)\.)?"?("([^"]|"")+"|[^"]+)$~', $match[2], $match2)) { |
|
215
|
|
|
$match2 = array_pad($match2, 5, ''); |
|
216
|
|
|
$foreignKey->schema = str_replace('""', '"', preg_replace('~^"(.+)"$~', '\1', $match2[2])); |
|
217
|
|
|
$foreignKey->table = str_replace('""', '"', preg_replace('~^"(.+)"$~', '\1', $match2[4])); |
|
218
|
|
|
} |
|
219
|
|
|
|
|
220
|
|
|
$foreignKey->onDelete = preg_match("~ON DELETE ($onActions)~", $match[4], $match2) ? $match2[1] : 'NO ACTION'; |
|
221
|
|
|
$foreignKey->onUpdate = preg_match("~ON UPDATE ($onActions)~", $match[4], $match2) ? $match2[1] : 'NO ACTION'; |
|
222
|
|
|
|
|
223
|
|
|
return $foreignKey; |
|
224
|
|
|
} |
|
225
|
|
|
} |
|
226
|
|
|
|