Descending indexes

This commit is contained in:
Jakub Vrana 2013-06-25 09:42:47 -07:00
parent c8248bb19c
commit 5f370927f1
10 changed files with 57 additions and 25 deletions

View file

@ -340,15 +340,17 @@ WHERE o.schema_id = SCHEMA_ID(" . q(get_schema()) . ") AND o.type IN ('S', 'U',
function indexes($table, $connection2 = null) {
$return = array();
// sp_statistics doesn't return information about primary key
foreach (get_rows("SELECT i.name, key_ordinal, is_unique, is_primary_key, c.name AS column_name
foreach (get_rows("SELECT i.name, key_ordinal, is_unique, is_primary_key, c.name AS column_name, is_descending_key
FROM sys.indexes i
INNER JOIN sys.index_columns ic ON i.object_id = ic.object_id AND i.index_id = ic.index_id
INNER JOIN sys.columns c ON ic.object_id = c.object_id AND ic.column_id = c.column_id
WHERE OBJECT_NAME(i.object_id) = " . q($table)
, $connection2) as $row) {
$return[$row["name"]]["type"] = ($row["is_primary_key"] ? "PRIMARY" : ($row["is_unique"] ? "UNIQUE" : "INDEX"));
$return[$row["name"]]["lengths"] = array();
$return[$row["name"]]["columns"][$row["key_ordinal"]] = $row["column_name"];
$name = $row["name"];
$return[$name]["type"] = ($row["is_primary_key"] ? "PRIMARY" : ($row["is_unique"] ? "UNIQUE" : "INDEX"));
$return[$name]["lengths"] = array();
$return[$name]["columns"][$row["key_ordinal"]] = $row["column_name"];
$return[$name]["descs"][$row["key_ordinal"]] = ($row["is_descending_key"] ? '1' : null);
}
return $return;
}

View file

@ -445,6 +445,7 @@ if (!defined("DRIVER")) {
$return[$row["Key_name"]]["type"] = ($row["Key_name"] == "PRIMARY" ? "PRIMARY" : ($row["Index_type"] == "FULLTEXT" ? "FULLTEXT" : ($row["Non_unique"] ? "INDEX" : "UNIQUE")));
$return[$row["Key_name"]]["columns"][] = $row["Column_name"];
$return[$row["Key_name"]]["lengths"][] = $row["Sub_part"];
$return[$row["Key_name"]]["descs"][] = null;
}
return $return;
}

View file

@ -245,9 +245,11 @@ FROM user_ind_columns uic
LEFT JOIN user_constraints uc ON uic.index_name = uc.constraint_name AND uic.table_name = uc.table_name
WHERE uic.table_name = " . q($table) . "
ORDER BY uc.constraint_type, uic.column_position", $connection2) as $row) {
$return[$row["INDEX_NAME"]]["type"] = ($row["CONSTRAINT_TYPE"] == "P" ? "PRIMARY" : ($row["CONSTRAINT_TYPE"] == "U" ? "UNIQUE" : "INDEX"));
$return[$row["INDEX_NAME"]]["columns"][] = $row["COLUMN_NAME"];
$return[$row["INDEX_NAME"]]["lengths"][] = ($row["CHAR_LENGTH"] && $row["CHAR_LENGTH"] != $row["COLUMN_LENGTH"] ? $row["CHAR_LENGTH"] : null);
$index_name = $row["INDEX_NAME"];
$return[$index_name]["type"] = ($row["CONSTRAINT_TYPE"] == "P" ? "PRIMARY" : ($row["CONSTRAINT_TYPE"] == "U" ? "UNIQUE" : "INDEX"));
$return[$index_name]["columns"][] = $row["COLUMN_NAME"];
$return[$index_name]["lengths"][] = ($row["CHAR_LENGTH"] && $row["CHAR_LENGTH"] != $row["COLUMN_LENGTH"] ? $row["CHAR_LENGTH"] : null);
$return[$index_name]["descs"][] = ($row["DESCEND"] ? '1' : null);
}
return $return;
}

View file

@ -268,13 +268,18 @@ ORDER BY a.attnum"
$return = array();
$table_oid = $connection2->result("SELECT oid FROM pg_class WHERE relnamespace = (SELECT oid FROM pg_namespace WHERE nspname = current_schema()) AND relname = " . q($table));
$columns = get_key_vals("SELECT attnum, attname FROM pg_attribute WHERE attrelid = $table_oid AND attnum > 0", $connection2);
foreach (get_rows("SELECT relname, indisunique::int, indisprimary::int, indkey FROM pg_index i, pg_class ci WHERE i.indrelid = $table_oid AND ci.oid = i.indexrelid", $connection2) as $row) {
$return[$row["relname"]]["type"] = ($row["indisprimary"] ? "PRIMARY" : ($row["indisunique"] ? "UNIQUE" : "INDEX"));
$return[$row["relname"]]["columns"] = array();
foreach (get_rows("SELECT relname, indisunique::int, indisprimary::int, indkey, indoption FROM pg_index i, pg_class ci WHERE i.indrelid = $table_oid AND ci.oid = i.indexrelid", $connection2) as $row) {
$relname = $row["relname"];
$return[$relname]["type"] = ($row["indisprimary"] ? "PRIMARY" : ($row["indisunique"] ? "UNIQUE" : "INDEX"));
$return[$relname]["columns"] = array();
foreach (explode(" ", $row["indkey"]) as $indkey) {
$return[$row["relname"]]["columns"][] = $columns[$indkey];
$return[$relname]["columns"][] = $columns[$indkey];
}
$return[$row["relname"]]["lengths"] = array();
$return[$relname]["descs"] = array();
foreach (explode(" ", $row["indoption"]) as $indoption) {
$return[$relname]["descs"][] = ($indoption ? '1' : null); //! check what the bits mean
}
$return[$relname]["lengths"] = array();
}
return $return;
}
@ -405,6 +410,7 @@ ORDER BY conkey, conname") as $row) {
$queries = array();
foreach ($alter as $val) {
if ($val[0] != "INDEX") {
//! descending UNIQUE indexes results in syntax error
$create[] = ($val[2] == "DROP"
? "\nDROP CONSTRAINT " . idf_escape($val[1])
: "\nADD" . ($val[1] != "" ? " CONSTRAINT " . idf_escape($val[1]) : "") . " $val[0] " . ($val[0] == "PRIMARY" ? "KEY " : "") . $val[2]

View file

@ -305,11 +305,14 @@ if (isset($_GET["sqlite"]) || isset($_GET["sqlite2"])) {
$return[""] = array("type" => "PRIMARY", "columns" => $primary, "lengths" => array());
}
foreach (get_rows("PRAGMA index_list(" . table($table) . ")") as $row) {
if (!ereg("^sqlite_", $row["name"])) {
$return[$row["name"]]["type"] = ($row["unique"] ? "UNIQUE" : "INDEX");
$return[$row["name"]]["lengths"] = array();
foreach (get_rows("PRAGMA index_info(" . idf_escape($row["name"]) . ")") as $row1) {
$return[$row["name"]]["columns"][] = $row1["name"];
$name = $row["name"];
if (!ereg("^sqlite_", $name)) {
$return[$name]["type"] = ($row["unique"] ? "UNIQUE" : "INDEX");
$return[$name]["lengths"] = array();
$return[$name]["descs"] = array();
foreach (get_rows("PRAGMA index_info(" . idf_escape($name) . ")") as $row1) {
$return[$name]["columns"][] = $row1["name"];
$return[$name]["descs"][] = null; // information about DESC is not available anywhere
}
}
}

View file

@ -19,14 +19,17 @@ if ($_POST && !$error && !$_POST["add"]) {
if (in_array($index["type"], $index_types)) {
$columns = array();
$lengths = array();
$descs = array();
$set = array();
ksort($index["columns"]);
foreach ($index["columns"] as $key => $column) {
if ($column != "") {
$length = $index["lengths"][$key];
$set[] = idf_escape($column) . ($length ? "(" . (+$length) . ")" : "");
$desc = $index["descs"][$key];
$set[] = idf_escape($column) . ($length ? "(" . (+$length) . ")" : "") . ($desc ? " DESC" : "");
$columns[] = $column;
$lengths[] = ($length ? $length : null);
$descs[] = $desc;
}
}
@ -35,7 +38,12 @@ if ($_POST && !$error && !$_POST["add"]) {
if ($existing) {
ksort($existing["columns"]);
ksort($existing["lengths"]);
if ($index["type"] == $existing["type"] && array_values($existing["columns"]) === $columns && (!$existing["lengths"] || array_values($existing["lengths"]) === $lengths)) {
ksort($existing["descs"]);
if ($index["type"] == $existing["type"]
&& array_values($existing["columns"]) === $columns
&& (!$existing["lengths"] || array_values($existing["lengths"]) === $lengths)
&& array_values($existing["descs"]) === $descs
) {
// skip existing index
unset($indexes[$name]);
continue;
@ -66,7 +74,11 @@ if ($_POST["add"]) {
}
}
$index = end($row["indexes"]);
if ($index["type"] || array_filter($index["columns"], 'strlen') || array_filter($index["lengths"], 'strlen')) {
if ($index["type"]
|| array_filter($index["columns"], 'strlen')
|| array_filter($index["lengths"], 'strlen')
|| array_filter($index["descs"])
) {
$row["indexes"][] = array("columns" => array(1 => ""));
}
}
@ -92,7 +104,9 @@ foreach ($row["indexes"] as $index) {
$i = 1;
foreach ($index["columns"] as $key => $column) {
echo "<span>" . html_select("indexes[$j][columns][$i]", array(-1 => "") + $fields, $column, ($i == count($index["columns"]) ? "indexesAddColumn" : "indexesChangeColumn") . "(this, '" . js_escape($jush == "sql" ? "" : $_GET["indexes"] . "_") . "');");
echo "<input type='number' name='indexes[$j][lengths][$i]' class='size' value='" . h($index["lengths"][$key]) . "'> </span>"; //! hide for non-MySQL drivers, add ASC|DESC
echo ($jush == "sql" || $jush == "mssql" ? "<input type='number' name='indexes[$j][lengths][$i]' class='size' value='" . h($index["lengths"][$key]) . "'>" : "");
echo ($jush != "sql" ? checkbox("indexes[$j][descs][$i]", 1, $index["descs"][$key], lang('descending')) : "");
echo " </span>";
$i++;
}

View file

@ -35,7 +35,10 @@ if ($fields) {
ksort($index["columns"]); // enforce correct columns order
$print = array();
foreach ($index["columns"] as $key => $val) {
$print[] = "<i>" . h($val) . "</i>" . ($index["lengths"][$key] ? "(" . $index["lengths"][$key] . ")" : "");
$print[] = "<i>" . h($val) . "</i>"
. ($index["lengths"][$key] ? "(" . $index["lengths"][$key] . ")" : "")
. ($index["descs"][$key] ? " DESC" : "")
;
}
echo "<tr title='" . h($name) . "'><th>$index[type]<td>" . implode(", ", $print) . "\n";
}

View file

@ -10,6 +10,7 @@ Send 404 for invalid database and schema
Fix title and links on invalid table pages
Display error on invalid alter table and view pages
MySQL: Speed up updating rows without numeric or UTF-8 primary key
Non-MySQL: Descending indexes
PostgreSQL: Fix detecting oid column in PDO
PostgreSQL: Handle timestamp types (bug #3614086)
Add Korean translation

View file

@ -357,6 +357,7 @@ ORDER BY ORDINAL_POSITION", null, "") as $row) { //! requires MySQL 5
}
foreach (($index_order != "" ? array($indexes[$index_order]) : $indexes) as $index) {
if ($index_order != "" || $index["type"] == "INDEX") {
$has_desc = array_filter($index["descs"]);
$desc = false;
foreach ($index["columns"] as $val) {
if (ereg('date|timestamp', $fields[$val]["type"])) {
@ -365,8 +366,8 @@ ORDER BY ORDINAL_POSITION", null, "") as $row) { //! requires MySQL 5
}
}
$return = array();
foreach ($index["columns"] as $val) {
$return[] = idf_escape($val) . ($desc ? " DESC" : "");
foreach ($index["columns"] as $key => $val) {
$return[] = idf_escape($val) . (($has_desc ? $index["descs"][$key] : $desc) ? " DESC" : "");
}
return $return;
}

View file

@ -24,7 +24,6 @@ Data longer than max_allowed_packet can be sent by mysqli_stmt_send_long_data()
SQLite:
Copy tables
ASC and DESC instead of text length in index
Delimiter in export and SQL command
Backward keys in Editor