You can not select more than 25 topics Topics must start with a letter or number, can include dashes ('-') and can be up to 35 characters long.

439 lines
15KB

  1. <?php
  2. /**
  3. * @link http://www.yiiframework.com/
  4. * @copyright Copyright (c) 2008 Yii Software LLC
  5. * @license http://www.yiiframework.com/license/
  6. */
  7. namespace yii\db\pgsql;
  8. use yii\db\Expression;
  9. use yii\db\TableSchema;
  10. use yii\db\ColumnSchema;
  11. /**
  12. * Schema is the class for retrieving metadata from a PostgreSQL database
  13. * (version 9.x and above).
  14. *
  15. * @author Gevik Babakhani <gevikb@gmail.com>
  16. * @since 2.0
  17. */
  18. class Schema extends \yii\db\Schema
  19. {
  20. /**
  21. * @var string the default schema used for the current session.
  22. */
  23. public $defaultSchema = 'public';
  24. /**
  25. * @var array mapping from physical column types (keys) to abstract
  26. * column types (values)
  27. * @see http://www.postgresql.org/docs/current/static/datatype.html#DATATYPE-TABLE
  28. */
  29. public $typeMap = [
  30. 'bit' => self::TYPE_INTEGER,
  31. 'bit varying' => self::TYPE_INTEGER,
  32. 'varbit' => self::TYPE_INTEGER,
  33. 'bool' => self::TYPE_BOOLEAN,
  34. 'boolean' => self::TYPE_BOOLEAN,
  35. 'box' => self::TYPE_STRING,
  36. 'circle' => self::TYPE_STRING,
  37. 'point' => self::TYPE_STRING,
  38. 'line' => self::TYPE_STRING,
  39. 'lseg' => self::TYPE_STRING,
  40. 'polygon' => self::TYPE_STRING,
  41. 'path' => self::TYPE_STRING,
  42. 'character' => self::TYPE_STRING,
  43. 'char' => self::TYPE_STRING,
  44. 'character varying' => self::TYPE_STRING,
  45. 'varchar' => self::TYPE_STRING,
  46. 'text' => self::TYPE_TEXT,
  47. 'bytea' => self::TYPE_BINARY,
  48. 'cidr' => self::TYPE_STRING,
  49. 'inet' => self::TYPE_STRING,
  50. 'macaddr' => self::TYPE_STRING,
  51. 'real' => self::TYPE_FLOAT,
  52. 'float4' => self::TYPE_FLOAT,
  53. 'double precision' => self::TYPE_DOUBLE,
  54. 'float8' => self::TYPE_DOUBLE,
  55. 'decimal' => self::TYPE_DECIMAL,
  56. 'numeric' => self::TYPE_DECIMAL,
  57. 'money' => self::TYPE_MONEY,
  58. 'smallint' => self::TYPE_SMALLINT,
  59. 'int2' => self::TYPE_SMALLINT,
  60. 'int4' => self::TYPE_INTEGER,
  61. 'int' => self::TYPE_INTEGER,
  62. 'integer' => self::TYPE_INTEGER,
  63. 'bigint' => self::TYPE_BIGINT,
  64. 'int8' => self::TYPE_BIGINT,
  65. 'oid' => self::TYPE_BIGINT, // should not be used. it's pg internal!
  66. 'smallserial' => self::TYPE_SMALLINT,
  67. 'serial2' => self::TYPE_SMALLINT,
  68. 'serial4' => self::TYPE_INTEGER,
  69. 'serial' => self::TYPE_INTEGER,
  70. 'bigserial' => self::TYPE_BIGINT,
  71. 'serial8' => self::TYPE_BIGINT,
  72. 'pg_lsn' => self::TYPE_BIGINT,
  73. 'date' => self::TYPE_DATE,
  74. 'interval' => self::TYPE_STRING,
  75. 'time without time zone' => self::TYPE_TIME,
  76. 'time' => self::TYPE_TIME,
  77. 'time with time zone' => self::TYPE_TIME,
  78. 'timetz' => self::TYPE_TIME,
  79. 'timestamp without time zone' => self::TYPE_TIMESTAMP,
  80. 'timestamp' => self::TYPE_TIMESTAMP,
  81. 'timestamp with time zone' => self::TYPE_TIMESTAMP,
  82. 'timestamptz' => self::TYPE_TIMESTAMP,
  83. 'abstime' => self::TYPE_TIMESTAMP,
  84. 'tsquery' => self::TYPE_STRING,
  85. 'tsvector' => self::TYPE_STRING,
  86. 'txid_snapshot' => self::TYPE_STRING,
  87. 'unknown' => self::TYPE_STRING,
  88. 'uuid' => self::TYPE_STRING,
  89. 'json' => self::TYPE_STRING,
  90. 'jsonb' => self::TYPE_STRING,
  91. 'xml' => self::TYPE_STRING
  92. ];
  93. /**
  94. * Creates a query builder for the PostgreSQL database.
  95. * @return QueryBuilder query builder instance
  96. */
  97. public function createQueryBuilder()
  98. {
  99. return new QueryBuilder($this->db);
  100. }
  101. /**
  102. * Resolves the table name and schema name (if any).
  103. * @param TableSchema $table the table metadata object
  104. * @param string $name the table name
  105. */
  106. protected function resolveTableNames($table, $name)
  107. {
  108. $parts = explode('.', str_replace('"', '', $name));
  109. if (isset($parts[1])) {
  110. $table->schemaName = $parts[0];
  111. $table->name = $parts[1];
  112. } else {
  113. $table->schemaName = $this->defaultSchema;
  114. $table->name = $name;
  115. }
  116. $table->fullName = $table->schemaName !== $this->defaultSchema ? $table->schemaName . '.' . $table->name : $table->name;
  117. }
  118. /**
  119. * Quotes a table name for use in a query.
  120. * A simple table name has no schema prefix.
  121. * @param string $name table name
  122. * @return string the properly quoted table name
  123. */
  124. public function quoteSimpleTableName($name)
  125. {
  126. return strpos($name, '"') !== false ? $name : '"' . $name . '"';
  127. }
  128. /**
  129. * Loads the metadata for the specified table.
  130. * @param string $name table name
  131. * @return TableSchema|null driver dependent table metadata. Null if the table does not exist.
  132. */
  133. public function loadTableSchema($name)
  134. {
  135. $table = new TableSchema();
  136. $this->resolveTableNames($table, $name);
  137. if ($this->findColumns($table)) {
  138. $this->findConstraints($table);
  139. return $table;
  140. } else {
  141. return null;
  142. }
  143. }
  144. /**
  145. * Returns all table names in the database.
  146. * @param string $schema the schema of the tables. Defaults to empty string, meaning the current or default schema.
  147. * @return array all table names in the database. The names have NO schema name prefix.
  148. */
  149. protected function findTableNames($schema = '')
  150. {
  151. if ($schema === '') {
  152. $schema = $this->defaultSchema;
  153. }
  154. $sql = <<<EOD
  155. SELECT table_name, table_schema FROM information_schema.tables
  156. WHERE table_schema=:schema AND table_type='BASE TABLE'
  157. EOD;
  158. $command = $this->db->createCommand($sql);
  159. $command->bindParam(':schema', $schema);
  160. $rows = $command->queryAll();
  161. $names = [];
  162. foreach ($rows as $row) {
  163. $names[] = $row['table_name'];
  164. }
  165. return $names;
  166. }
  167. /**
  168. * Collects the foreign key column details for the given table.
  169. * @param TableSchema $table the table metadata
  170. */
  171. protected function findConstraints($table)
  172. {
  173. $tableName = $this->quoteValue($table->name);
  174. $tableSchema = $this->quoteValue($table->schemaName);
  175. //We need to extract the constraints de hard way since:
  176. //http://www.postgresql.org/message-id/26677.1086673982@sss.pgh.pa.us
  177. $sql = <<<SQL
  178. select
  179. (select string_agg(attname,',') attname from pg_attribute where attrelid=ct.conrelid and attnum = any(ct.conkey)) as columns,
  180. fc.relname as foreign_table_name,
  181. fns.nspname as foreign_table_schema,
  182. (select string_agg(attname,',') attname from pg_attribute where attrelid=ct.confrelid and attnum = any(ct.confkey)) as foreign_columns
  183. from
  184. pg_constraint ct
  185. inner join pg_class c on c.oid=ct.conrelid
  186. inner join pg_namespace ns on c.relnamespace=ns.oid
  187. left join pg_class fc on fc.oid=ct.confrelid
  188. left join pg_namespace fns on fc.relnamespace=fns.oid
  189. where
  190. ct.contype='f'
  191. and c.relname={$tableName}
  192. and ns.nspname={$tableSchema}
  193. SQL;
  194. $constraints = $this->db->createCommand($sql)->queryAll();
  195. foreach ($constraints as $constraint) {
  196. $columns = explode(',', $constraint['columns']);
  197. $fcolumns = explode(',', $constraint['foreign_columns']);
  198. if ($constraint['foreign_table_schema'] !== $this->defaultSchema) {
  199. $foreignTable = $constraint['foreign_table_schema'] . '.' . $constraint['foreign_table_name'];
  200. } else {
  201. $foreignTable = $constraint['foreign_table_name'];
  202. }
  203. $citem = [$foreignTable];
  204. foreach ($columns as $idx => $column) {
  205. $citem[$column] = $fcolumns[$idx];
  206. }
  207. $table->foreignKeys[] = $citem;
  208. }
  209. }
  210. /**
  211. * Gets information about given table unique indexes.
  212. * @param TableSchema $table the table metadata
  213. * @return array with index names, columns and if it is an expression tree
  214. */
  215. protected function getUniqueIndexInformation($table)
  216. {
  217. $tableName = $this->quoteValue($table->name);
  218. $tableSchema = $this->quoteValue($table->schemaName);
  219. $sql = <<<SQL
  220. SELECT
  221. i.relname as indexname,
  222. ARRAY(
  223. SELECT pg_get_indexdef(idx.indexrelid, k + 1, True)
  224. FROM generate_subscripts(idx.indkey, 1) AS k
  225. ORDER BY k
  226. ) AS indexcolumns,
  227. idx.indexprs IS NOT NULL AS indexprs
  228. FROM pg_index idx
  229. INNER JOIN pg_class i ON i.oid = idx.indexrelid
  230. INNER JOIN pg_class c ON c.oid = idx.indrelid
  231. INNER JOIN pg_namespace ns ON c.relnamespace = ns.oid
  232. WHERE idx.indisprimary != True
  233. AND idx.indisunique = True
  234. AND c.relname = {$tableName}
  235. AND ns.nspname = {$tableSchema}
  236. ;
  237. SQL;
  238. return $this->db->createCommand($sql)->queryAll();
  239. }
  240. /**
  241. * Returns all unique indexes for the given table.
  242. * Each array element is of the following structure:
  243. *
  244. * ~~~
  245. * [
  246. * 'IndexName1' => ['col1' [, ...]],
  247. * 'IndexName2' => ['col2' [, ...]],
  248. * ]
  249. * ~~~
  250. *
  251. * @param TableSchema $table the table metadata
  252. * @return array all unique indexes for the given table.
  253. */
  254. public function findUniqueIndexes($table)
  255. {
  256. $indexes = $this->getUniqueIndexInformation($table);
  257. $uniqueIndexes = [];
  258. foreach ($indexes as $index) {
  259. $indexName = $index['indexname'];
  260. if ($index['indexprs']) {
  261. // Index is an expression like "lower(colname::text)"
  262. $indexColumns = preg_replace("/.*\(([^\:]+).*/mi", "$1", $index['indexcolumns']);
  263. } else {
  264. $indexColumns = array_map('trim', explode(',', str_replace(['{', '}', '"', '\\'], '', $index['indexcolumns'])));
  265. }
  266. $uniqueIndexes[$indexName] = $indexColumns;
  267. }
  268. return $uniqueIndexes;
  269. }
  270. /**
  271. * Collects the metadata of table columns.
  272. * @param TableSchema $table the table metadata
  273. * @return boolean whether the table exists in the database
  274. */
  275. protected function findColumns($table)
  276. {
  277. $tableName = $this->db->quoteValue($table->name);
  278. $schemaName = $this->db->quoteValue($table->schemaName);
  279. $sql = <<<SQL
  280. SELECT
  281. d.nspname AS table_schema,
  282. c.relname AS table_name,
  283. a.attname AS column_name,
  284. t.typname AS data_type,
  285. a.attlen AS character_maximum_length,
  286. pg_catalog.col_description(c.oid, a.attnum) AS column_comment,
  287. a.atttypmod AS modifier,
  288. a.attnotnull = false AS is_nullable,
  289. CAST(pg_get_expr(ad.adbin, ad.adrelid) AS varchar) AS column_default,
  290. coalesce(pg_get_expr(ad.adbin, ad.adrelid) ~ 'nextval',false) AS is_autoinc,
  291. array_to_string((select array_agg(enumlabel) from pg_enum where enumtypid=a.atttypid)::varchar[],',') as enum_values,
  292. CASE atttypid
  293. WHEN 21 /*int2*/ THEN 16
  294. WHEN 23 /*int4*/ THEN 32
  295. WHEN 20 /*int8*/ THEN 64
  296. WHEN 1700 /*numeric*/ THEN
  297. CASE WHEN atttypmod = -1
  298. THEN null
  299. ELSE ((atttypmod - 4) >> 16) & 65535
  300. END
  301. WHEN 700 /*float4*/ THEN 24 /*FLT_MANT_DIG*/
  302. WHEN 701 /*float8*/ THEN 53 /*DBL_MANT_DIG*/
  303. ELSE null
  304. END AS numeric_precision,
  305. CASE
  306. WHEN atttypid IN (21, 23, 20) THEN 0
  307. WHEN atttypid IN (1700) THEN
  308. CASE
  309. WHEN atttypmod = -1 THEN null
  310. ELSE (atttypmod - 4) & 65535
  311. END
  312. ELSE null
  313. END AS numeric_scale,
  314. CAST(
  315. information_schema._pg_char_max_length(information_schema._pg_truetypid(a, t), information_schema._pg_truetypmod(a, t))
  316. AS numeric
  317. ) AS size,
  318. a.attnum = any (ct.conkey) as is_pkey
  319. FROM
  320. pg_class c
  321. LEFT JOIN pg_attribute a ON a.attrelid = c.oid
  322. LEFT JOIN pg_attrdef ad ON a.attrelid = ad.adrelid AND a.attnum = ad.adnum
  323. LEFT JOIN pg_type t ON a.atttypid = t.oid
  324. LEFT JOIN pg_namespace d ON d.oid = c.relnamespace
  325. LEFT join pg_constraint ct on ct.conrelid=c.oid and ct.contype='p'
  326. WHERE
  327. a.attnum > 0 and t.typname != ''
  328. and c.relname = {$tableName}
  329. and d.nspname = {$schemaName}
  330. ORDER BY
  331. a.attnum;
  332. SQL;
  333. $columns = $this->db->createCommand($sql)->queryAll();
  334. if (empty($columns)) {
  335. return false;
  336. }
  337. foreach ($columns as $column) {
  338. $column = $this->loadColumnSchema($column);
  339. $table->columns[$column->name] = $column;
  340. if ($column->isPrimaryKey) {
  341. $table->primaryKey[] = $column->name;
  342. if ($table->sequenceName === null && preg_match("/nextval\\('\"?\\w+\"?\.?\"?\\w+\"?'(::regclass)?\\)/", $column->defaultValue) === 1) {
  343. $table->sequenceName = preg_replace(['/nextval/', '/::/', '/regclass/', '/\'\)/', '/\(\'/'], '', $column->defaultValue);
  344. }
  345. $column->defaultValue = null;
  346. } elseif ($column->defaultValue) {
  347. if ($column->type === 'timestamp' && $column->defaultValue === 'now()') {
  348. $column->defaultValue = new Expression($column->defaultValue);
  349. } elseif ($column->type === 'boolean') {
  350. $column->defaultValue = ($column->defaultValue === 'true');
  351. } elseif (stripos($column->dbType, 'bit') === 0 || stripos($column->dbType, 'varbit') === 0) {
  352. $column->defaultValue = bindec(trim($column->defaultValue, 'B\''));
  353. } elseif (preg_match("/^'(.*?)'::/", $column->defaultValue, $matches)) {
  354. $column->defaultValue = $matches[1];
  355. } elseif (preg_match("/^(.*?)::/", $column->defaultValue, $matches)) {
  356. $column->defaultValue = $column->phpTypecast($matches[1]);
  357. } else {
  358. $column->defaultValue = $column->phpTypecast($column->defaultValue);
  359. }
  360. }
  361. }
  362. return true;
  363. }
  364. /**
  365. * Loads the column information into a [[ColumnSchema]] object.
  366. * @param array $info column information
  367. * @return ColumnSchema the column schema object
  368. */
  369. protected function loadColumnSchema($info)
  370. {
  371. $column = $this->createColumnSchema();
  372. $column->allowNull = $info['is_nullable'];
  373. $column->autoIncrement = $info['is_autoinc'];
  374. $column->comment = $info['column_comment'];
  375. $column->dbType = $info['data_type'];
  376. $column->defaultValue = $info['column_default'];
  377. $column->enumValues = ($info['enum_values'] !== null) ? explode(',', str_replace(["''"], ["'"], $info['enum_values'])) : null;
  378. $column->unsigned = false; // has no meaning in PG
  379. $column->isPrimaryKey = $info['is_pkey'];
  380. $column->name = $info['column_name'];
  381. $column->precision = $info['numeric_precision'];
  382. $column->scale = $info['numeric_scale'];
  383. $column->size = $info['size'] === null ? null : (int) $info['size'];
  384. if (isset($this->typeMap[$column->dbType])) {
  385. $column->type = $this->typeMap[$column->dbType];
  386. } else {
  387. $column->type = self::TYPE_STRING;
  388. }
  389. $column->phpType = $this->getColumnPhpType($column);
  390. return $column;
  391. }
  392. }